Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 35.3Mb
PDF (A4) - 35.3Mb
PDF (RPM) - 34.3Mb
EPUB - 8.6Mb
HTML Download (TGZ) - 8.4Mb
HTML Download (Zip) - 8.4Mb
HTML Download (RPM) - 7.2Mb
Eclipse Doc Plugin (TGZ) - 9.2Mb
Eclipse Doc Plugin (Zip) - 11.4Mb
Man Pages (TGZ) - 200.3Kb
Man Pages (Zip) - 305.6Kb
Info (Gzip) - 3.3Mb
Info (Zip) - 3.3Mb
Excerpts from this Manual

MySQL 5.7 Reference Manual  /  ...  /  mysqlbinlog — Utility for Processing Binary Log Files

5.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 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 6.4.4, “The Binary Log”, and Section 18.2.4, “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 18.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 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.

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 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 8.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 5.2.6, “Using Option Files”.

Table 5.19 mysqlbinlog Options

FormatDescriptionIntroducedDeprecated
--base64-outputPrint binary log entries using base-64 encoding  
--bind-addressUse specified network interface to connect to MySQL Server  
--binlog-row-event-max-sizeBinary log max event size  
--character-sets-dirDirectory where character sets are installed  
--connection-server-idUsed for testing and debugging. See text for applicable default values and other particulars.5.7.5 
--databaseList entries for just this database  
--debugWrite debugging log  
--debug-checkPrint debugging information when program exits  
--debug-infoPrint debugging information, memory, and CPU statistics when program exits  
--default-authAuthentication plugin to use  
--defaults-extra-fileRead named option file in addition to usual option files  
--defaults-fileRead only named option file  
--defaults-group-suffixOption group suffix value  
--disable-log-binDisable binary logging  
--exclude-gtidsDo not show any of the groups in the GTID set provided  
--force-if-openRead binary log files even if open or not closed properly  
--force-readIf mysqlbinlog reads a binary log event that it does not recognize, it prints a warning  
--helpDisplay help message and exit  
--hexdumpDisplay a hex dump of the log in comments  
--hostConnect to MySQL server on given host  
--idempotentCause the server to use idempotent mode while processing binary log updates from this session only5.7.0 
--include-gtidsShow only the groups in the GTID set provided  
--local-loadPrepare local temporary files for LOAD DATA INFILE in the specified directory  
--login-pathRead login path options from .mylogin.cnf  
--no-defaultsRead no option files  
--offsetSkip the first N entries in the log  
--passwordPassword to use when connecting to server  
--plugin-dirDirectory where plugins are installed  
--portTCP/IP port number to use for connection  
--print-defaultsPrint default options  
--protocolConnection protocol to use  
--rawWrite events in raw (binary) format to output files  
--read-from-remote-masterRead the binary log from a MySQL master rather than reading a local log file  
--read-from-remote-serverRead binary log from MySQL server rather than local log file  
--result-fileDirect output to named file  
--rewrite-dbCreate rewrite rules for databases when playing back from logs written in row-based format. Can be used multiple times.5.7.1 
--secure-authDo not send passwords to server in old (pre-4.1) format5.7.45.7.5
--server-idExtract only those events created by the server having the given server ID  
--server-id-bitsTell 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  
--set-charsetAdd a SET NAMES charset_name statement to the output  
--shared-memory-base-nameThe name of shared memory to use for shared-memory connections  
--short-formDisplay only the statements contained in the log  
--skip-gtidsDo not print any GTIDs; use this when writing a dump file from binary logs containing GTIDs.  
--socketFor connections to localhost, the Unix socket file to use  
--sslEnable secure connection5.7.3 
--ssl-caPath of file that contains list of trusted SSL CAs5.7.3 
--ssl-capathPath of directory that contains trusted SSL CA certificates in PEM format5.7.3 
--ssl-certPath of file that contains X509 certificate in PEM format5.7.3 
--ssl-cipherList of permitted ciphers to use for connection encryption5.7.3 
--ssl-crlPath of file that contains certificate revocation lists  
--ssl-crlpathPath of directory that contains certificate revocation list files  
--ssl-keyPath of file that contains X509 key in PEM format5.7.3 
--ssl-modeSecurity state of connection to server5.7.11 
--ssl-verify-server-certVerify server certificate Common Name value against host name used when connecting to server5.7.3 
--start-datetimeRead binary log from first event with timestamp equal to or later than datetime argument  
--start-positionRead binary log from first event with position equal to or greater than argument  
--stop-datetimeStop reading binary log at first event with timestamp equal to or greater than datetime argument  
--stop-neverStay connected to server after reading last binary log file  
--stop-never-slave-server-idSlave server ID to report when connecting to server  
--stop-positionStop reading binary log at first event with position equal to or greater than argument  
--tls-versionProtocols permitted for secure connections5.7.10 
--to-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  
--userMySQL user name to use when connecting to server  
--verboseReconstruct row events as SQL statements  
--verify-binlog-checksumVerify checksums in binary log  
--versionDisplay version information and exit  

  • --help, -?

    Display a help message and exit.

  • --base64-output=value

    This option determines when events should be displayed encoded as base-64 strings using BINLOG statements. The option has these permissible values (not case sensitive):

    • AUTO ("automatic") or UNSPEC ("unspecified") displays BINLOG statements automatically when necessary (that is, for format description events and row events). If no --base64-output option is given, the effect is the same as --base64-output=AUTO.

      Note

      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.

    • 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.

    For examples that show the effect of --base64-output and --verbose on row event output, see Section 5.6.7.2, “mysqlbinlog Row Event Display”.

  • --bind-address=ip_address

    On a computer having multiple network interfaces, use this option to select which interface to use for connecting to the MySQL server.

  • --binlog-row-event-max-size=N

    Command-Line Format--binlog-row-event-max-size=#
    Permitted Values (64-bit platforms)Typenumeric
    Default4294967040
    Min Value256
    Max Value18446744073709547520

    Specify the maximum size of a row-based binary log event, in bytes. Rows are grouped into events smaller than this size if possible. The value should be a multiple of 256. The default is 4GB.

  • --character-sets-dir=dir_name

    The directory where character sets are installed. See Section 11.5, “Character Set Configuration”.

  • --connection-server-id=server_id

    This option is used to test a MySQL server for support of the BINLOG_DUMP_NON_BLOCK connection flag, which was inadvertently removed in MySQL 5.6.5, and restored in MySQL 5.7.5 (Bug #18000079, Bug #71178). It is not required for normal operations.

    The effective default and minimum values for this option depend on whether mysqlbinlog is run in blocking mode or non-blocking mode. When mysqlbinlog is run in blocking mode, the default (and minimum) value is 1; when run in non-blocking mode, the default (and minimum) value is 0.

    This option was added in MySQL 5.7.5

  • --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 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-db depend on whether statement-based or row-based logging is in use.

    Statement-based logging.  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 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 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.

    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 modify t1 in the test database, regardless of whether USE was issued or what the default database is.

    If a server is running with binlog_format set to MIXED 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.)

    Prior to MySQL 5.7.1, the --database option did not work correctly with a log written by a GTID-enabled MySQL server. (Bug #15912728)

    When used together with the --rewrite-db option (available in MySQL 5.7.1 and later), 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.

  • --debug[=debug_options], -# [debug_options]

    Write a debugging log. A typical debug_options string is d:t:o,file_name. The default is d:t:o,/tmp/mysqlbinlog.trace.

  • --debug-check

    Print some debugging information when the program exits.

  • --debug-info

    Print debugging information and memory and CPU usage statistics when the program exits.

  • --default-auth=plugin

    A hint about the client-side authentication plugin to use. See Section 7.3.8, “Pluggable Authentication”.

  • --defaults-extra-file=file_name

    Read 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_name is interpreted relative to the current directory if given as a relative path name rather than a full path name.

  • --defaults-file=file_name

    Use only the given option file. If the file does not exist or is otherwise inaccessible, an error occurs. file_name is interpreted relative to the current directory if given as a relative path name rather than a full path name.

  • --defaults-group-suffix=str

    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=_other option is given, mysqlbinlog also reads the [client_other] and [mysqlbinlog_other] groups.

  • --disable-log-bin, -D

    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.

  • --exclude-gtids=gtid_set

    Do not display any of the groups listed in the gtid_set.

  • --force-if-open, -F

    Read binary log files even if they are open or were not closed properly.

  • --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 5.6.7.1, “mysqlbinlog Hex Dump Format”. The hex output can be helpful for replication debugging.

  • --host=host_name, -h host_name

    Get the binary log from the MySQL server on the given host.

  • --idempotent

    Tell the MySQL Server to use idempotent mode while processing updates; this causes suppression of any duplicate-key or key-not-found errors that the server encounters in the current session while processing updates. This option may prove useful whenever it is desirable or necessary to replay one or more binary logs to a MySQL Server which may not contain all of the data to which the logs refer.

    The scope of effect for this option includes the current mysqlbinlog client and session only.

    The --idempotent option was introduced in MySQL 5.7.0.

  • --include-gtids=gtid_set

    Display only the groups listed in the gtid_set.

  • --local-load=dir_name, -l dir_name

    Prepare local temporary files for LOAD DATA INFILE in the specified directory.

    Important

    These temporary files are not automatically removed by mysqlbinlog or any other MySQL program.

  • --login-path=name

    Read options from the named login path in the .mylogin.cnf login path file. A login path is an option group containing options that specify which MySQL server to connect to and which account to authenticate as. To create or modify a login path file, use the mysql_config_editor utility. See Section 5.6.6, “mysql_config_editor — MySQL Configuration Utility”.

  • --no-defaults

    Do not read any option files. If program startup fails due to reading unknown options from an option file, --no-defaults can be used to prevent them from being read.

    The exception is that the .mylogin.cnf file, if it exists, is read in all cases. This permits passwords to be specified in a safer way than on the command line even when --no-defaults is used. (.mylogin.cnf is created by the mysql_config_editor utility. See Section 5.6.6, “mysql_config_editor — MySQL Configuration Utility”.)

  • --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 7.1.2.1, “End-User Guidelines for Password Security”. You can use an option file to avoid giving the password on the command line.

  • --plugin-dir=dir_name

    The directory in which to look for plugins. Specify this option if the --default-auth option is used to specify an authentication plugin but mysqlbinlog does not find it. See Section 7.3.8, “Pluggable Authentication”.

  • --port=port_num, -P port_num

    The TCP/IP port number to use for connecting to a remote server.

  • --print-defaults

    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 5.2.2, “Connecting to the MySQL Server”.

  • --raw

    By default, mysqlbinlog reads binary log files and writes events in text format. The --raw option tells mysqlbinlog to write them in their original binary format. Its use requires that --read-from-remote-server also be used because the files are requested from a server. mysqlbinlog writes one output file for each file read from the server. The --raw option can be used to make a backup of a server's binary log. With the --stop-never option, the backup is live because mysqlbinlog stays connected to the server. By default, output files are written in the current directory with the same names as the original log files. Output file names can be modified using the --result-file option. For more information, see Section 5.6.7.3, “Using mysqlbinlog to Back Up Binary Log Files”.

  • --read-from-remote-master=type

    Read binary logs from a MySQL server with the COM_BINLOG_DUMP or COM_BINLOG_DUMP_GTID commands by setting the option value to either BINLOG-DUMP-NON-GTIDS or BINLOG-DUMP-GTIDS, respectively. If --read-from-remote-master=BINLOG-DUMP-GTIDS is combined with --exclude-gtids, transactions can be filtered out on the master, avoiding unnecessary network traffic.

    See also the description for --read-from-remote-server.

  • --read-from-remote-server, -R

    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.

    This option is like --read-from-remote-master=BINLOG-DUMP-NON-GTIDS.

  • --result-file=name, -r name

    Without the --raw option, this option indicates the file to which mysqlbinlog writes text output. With --raw, mysqlbinlog writes one binary output file for each log file transferred from the server, writing them by default in the current directory using the same names as the original log file. In this case, the --result-file option value is treated as a prefix that modifies output file names.

  • --rewrite-db='from_name->to_name'

    In MySQL 5.7.8 and later, when reading from a row-based or statement-based log, rewrite all occurrences of from_name to to_name. Rewriting is done on the rows, for row-based logs, as well as on the USE clauses, for statement-based logs. In MySQL versions prior to 5.7.8, this option was only for use when restoring tables logged using the row-based format.

    Warning

    Statements in which table names are qualified with database names are not rewritten to use the new name when using this option.

    The rewrite rule employed as a value for this option is a string having the form 'from_name->to_name', as shown previously, and for this reason must be enclosed by quotation marks.

    To employ multiple rewrite rules, specify the option multiple times, as shown here:

    shell> 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, if mysqlbinlog is started with --rewrite-db='mydb->yourdb' --database=yourdb, then all updates to any tables in databases mydb and yourdb are included in the output. On the other hand, if it is started with --rewrite-db='mydb->yourdb' --database=mydb, then mysqlbinlog 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.

    This option was added in MySQL 5.7.1.

  • --secure-auth

    Do not send passwords to the server in old (pre-4.1) format. This prevents connections except for servers that use the newer password format. This option was added in MySQL 5.7.4.

    As of MySQL 5.7.5, this option is deprecated and will be removed in a future MySQL release. It is always enabled and attempting to disable it (--skip-secure-auth, --secure-auth=0) produces an error. Before MySQL 5.7.5, this option is enabled by default but can be disabled.

    Note

    Passwords that use the pre-4.1 hashing method are less secure than passwords that use the native password hashing method and should be avoided. Pre-4.1 passwords are deprecated and support for them is removed in MySQL 5.7.5. For account upgrade instructions, see Section 7.5.1.3, “Migrating Away from Pre-4.1 Password Hashing and the mysql_old_password Plugin”.

  • --server-id=id

    Display only those events created by the server having the given server ID.

  • --server-id-bits=N

    Use only the first N bits of the server_id to 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-bits set to 32 enables this data to be seen.

    This option is supported only by the versions of mysqlbinlog supplied with the MySQL Cluster distribution, or built from the MySQL Cluster sources.

  • --set-charset=charset_name

    Add a SET NAMES charset_name statement to the output to specify the character set to be used for processing log files.

  • --shared-memory-base-name=name

    On 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-memory option to enable shared-memory connections.

  • --short-form, -s

    Display 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.

  • --skip-gtids[=(true|false)]

    Do not display any GTIDs in the output. This is needed when writing to a dump file from one or more binary logs containing GTIDs, as shown in this example:

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

    The use of this option is otherwise not normally recommended in production.

  • --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.

  • --ssl*

    Options that begin with --ssl specify whether to connect to the server using SSL and indicate where to find SSL keys and certificates. See Section 7.4.5, “Command Options for Secure Connections”.

  • --start-datetime=datetime

    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 8.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 8.3, “Example Backup and Recovery Strategy”.

  • --stop-datetime=datetime

    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 8.3, “Example Backup and Recovery Strategy”.

  • --stop-never

    This option is used with --read-from-remote-server. It tells mysqlbinlog to remain connected to the server. Otherwise mysqlbinlog exits when the last log file has been transferred from the server. --stop-never implies --to-last-log, so only the first log file to transfer need be named on the command line.

    --stop-never is commonly used with --raw to make a live binary log backup, but also can be used without --raw to maintain a continuous text display of log events as the server generates them.

  • --stop-never-slave-server-id=id

    With --stop-never, mysqlbinlog reports a server ID of 65535 when it connects to the server. --stop-never-slave-server-id explicitly specifies the server ID to report. It can be used to avoid a conflict with the ID of a slave server or another mysqlbinlog process. See Section 5.6.7.4, “Specifying the mysqlbinlog Server ID”.

  • --stop-position=N

    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 8.3, “Example Backup and Recovery Strategy”.

  • --tls-version=protocol_list

    The protocols permitted by the client for encrypted connections. The value is a comma-separated list containing one or more protocol names. The protocols that can be named for this option depend on the SSL library used to compile MySQL. For details, see Section 7.4.3, “Secure Connection Protocols and Ciphers”.

    This option was added in MySQL 5.7.10.

  • --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 this option is given twice, the output includes comments to indicate column data types and some metadata.

    For examples that show the effect of --base64-output and --verbose on row event output, see Section 5.6.7.2, “mysqlbinlog Row Event Display”.

  • --verify-binlog-checksum, -c

    Verify checksums in binary log files.

  • --version, -V

    Display version information and exit.

    In MySQL 5.7.1 and later, the mysqlbinlog version number shown when using this option is 3.4. (Bug #15894381, Bug #67643)

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

  • open_files_limit

    Specify the number of open file descriptors to reserve.

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 8.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 7.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-#-#.


User Comments
  Posted by Tom Mulkins on September 23, 2003
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
  Posted by KEvin on February 9, 2005
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...

  Posted by john danilson on September 8, 2006
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.
  Posted by Yiannis Mavridis on April 30, 2007
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
  Posted by Baron Schwartz on December 13, 2007
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.
  Posted by Jason Ho on August 19, 2008
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
  Posted by Jim Grill on September 19, 2008
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.
  Posted by Phillip Gee on March 11, 2009
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.
Sign Up Login You must be logged in to post a comment.