mysqlbinlog

You are viewing an old version of this article. View the current version here.

About mysqlbinlog

mysqlbinlog is a utility included with MariaDB for processing binary log files.

The MariaDB server's binary log is a set of files containing "events" which represent modifications to the contents of a MariaDB database. These events are written in a binary (i.e. non-human-readable) format. The mysqlbinlog utility is used to view these events in plain text.

More information about the binary log can be found here.

Using mysqlbinlog

Run mysqlbinlog from a command-line like this:

shell> mysqlbinlog [options] log_file ...

As an example, here is how you could display the contents of a binary log file named "mariadb-bin.000152":

shell> mysqlbinlog mariadb-bin.000152

If you are using statement-based logging (the default) the output includes the SQL statement, the ID of the server the statement was executed on, a timestamp, and how much time the statement took to execute. If you are using row-based logging the output of an event will not include an SQL statement but will instead output how individual rows were changed.

The output from mysqlbinlog can be used as input to the mysql client to redo the statements contained in a binary log. This is useful for recovering after a server crash. Here is an example:

shell> mysqlbinlog binlog-filenames | mysql -u root -p

If you would like to view and possibly edit the file before applying it to your database, use the '-r' flag to redirect the output to a file:

shell> mysqlbinlog -r filename binlog-filenames

You can then open the file and view it and delete any statements you don't want executed (such as an accidental DROP DATABASE). Once you are satisfied with the contents you can execute it with:

shell> mysql -u root -p < filename

Be careful to process multiple log files in a single connection, especially if one or more of them have any CREATE TEMPORARY TABLE ... statements. Temporary tables are dropped when the mysql client terminates, so if you are processing multiple log files one at a time (i.e. multiple connections) and one log file creates a temporary table and then a subsequent log file refers to the table you will get an 'unknown table' error.

To execute multiple logfiles using a single connection, list them all on the mysqlbinlog command line:

shell> mysqlbinlog mariadb-bin.000001 mariadb-bin.000002 | mysql -u root -p

If you need to manually edit the binlogs before executing them, combine them all into a single file before processing. Here is an example:

shell> mysqlbinlog mariadb-bin.000001 > /tmp/mariadb-bin.sql
shell> mysqlbinlog mariadb-bin.000002 >> /tmp/mariadb-bin.sql
shell> # make any edits
shell> mysql -u root -p -e "source /tmp/mariadb-bin.sql"

mysqlbinlog Options

The following options are supported by mysqlbinlog. They can be specified on the command line or in the [client] and [mysqlbinlog] option file groups.

short formlong formdefault valueDescriptionIntroduced
-?--helpDisplay a help statement.
--base64-output[=name]''(No Default Value)''Determine when the output statements should be base64-encoded BINLOG statements: 'never' disables it and works only for binlogs without row-based events; 'decode-rows' decodes row events into commented SQL statements if the --verbose option is also given; 'auto' prints base64 only when necessary (i.e., for row-based events and format description events); 'always' prints base64 whenever possible. 'always' is for debugging only and should not be used in a production system. If this argument is not given, the default is 'auto'; if it is given with no argument, 'always' is used.MySQL 5.1.5
--character-sets-dir=name(No default value)Directory where character sets are.
-d--database=name(No default value)List entries for just this database (local log only).
--debug-checkFALSECheck memory and open file usage at exit.MySQL 5.1.21
--debug-infoFALSEPrint some debug info at exit.MySQL 5.1.21
-D--disable-log-binFALSEDisable binary log. This is useful, if you enabled --to-last-log and are sending the output to the same MySQL server. This way you could avoid an endless loop. You would also like to use it when restoring after a crash to avoid duplication of the statements you already have. NOTE: you will need a SUPER privilege to use this option.
-F--force-if-openTRUEForce if binlog was not closed properly.
-f--force-readFALSEForce reading unknown binlog events.
-H--hexdumpFALSEAugment output with hexadecimal and ASCII event dump.MySQL 5.1.2
-h--host=name(No default value)Get the binlog from server.
-l--local-load=name(No default value)Prepare local temporary files for LOAD DATA INFILE in the specified directory.
-o--offset=#0Skip the first N entries.
-p--password[=name](No default value)Password to connect to remote server.
-P--port=#0Port number to use for connection or 0 for default to, in order of preference, my.cnf, $MYSQL_TCP_PORT, /etc/services, built-in default (3306).
--position=#4Deprecated. Use --start-position instead.
--protocol=name(No default value)The protocol of the connection (tcp,socket,pipe,memory).
-R--read-from-remote-serverFALSERead binary logs from a MySQL server
-r--result-file=name(No default value)Direct output to a given file.
--server-id=idnum0Extract only binlog entries created by the server having the given id.MySQL 5.1.4
--set-charset=character_set(No default value)Add 'SET NAMES character_set' to the output.MySQL 5.1.12
-s--short-formFALSEJust show regular queries: no extra info and no row-based events. This is for testing only, and should not be used in production systems. If you want to suppress base64-output, consider using --base64-output=never instead.
-S--socket=name(No default value)Socket file to use for connection.
--start-datetime=name(No default value)Start reading the binlog at first event having a datetime equal or posterior to the argument; the argument must be a date and time in the local time zone, in any format accepted by the MySQL server for DATETIME and TIMESTAMP types, for example: 2004-12-25 11:25:56 (you should probably use quotes for your shell to set it properly).
-j--start-position=#4Start reading the binlog at position N. Applies to the first binlog passed on the command line.
--stop-datetime=name(No default value)Stop reading the binlog at first event having a datetime equal or posterior to the argument; the argument must be a date and time in the local time zone, in any format accepted by the MySQL server for DATETIME and TIMESTAMP types, for example: 2004-12-25 11:25:56 (you should probably use quotes for your shell to set it properly).
--stop-position=#18446744073709551615Stop reading the binlog at position N. Applies to the last binlog passed on the command line.
-t--to-last-logFALSERequires -R. Will not stop at the end of the requested binlog but rather continue printing until the end of the last binlog of the MySQL server. If you send the output to the same MySQL server, that may lead to an endless loop.
-u--user=username(No default value)Connect to the remote server as username.
-v--verboseReconstruct SQL statements out of row events. -v -v adds comments on column data typesMySQL 5.1.28
-V--versionPrint version and exit.
--open_files_limit=# 64Used to reserve file descriptors for usage by this program
--rewrite-db=name(No default value)Updates to a database with a different name than the original. Example: rewrite-db='from->to'

For events that are binlogged as statements, rewriting the database constitutes changing a statement's default database from db1 to db2.

There is no statement analysis or rewrite of any kind, that is, if one specifies "db1.tbl" in the statement explicitly, that occurrence won't be changed to "db2.tbl".

Row-based events are rewritten correctly to use the new database name.

Filtering (e.g. with --database=name) happens after the database rewrites have been performed.

If you use this option on the command line and ">" has a special meaning to your command interpreter, quote the value (e.g. --rewrite-db="oldname->newname").
MariaDB 5.2.1

Comments

Comments loading...
Content reproduced on this site is the property of its respective owners, and this content is not reviewed in advance by MariaDB. The views, information and opinions expressed by this content do not necessarily represent those of MariaDB or any other party.