The binary log contains “events” that describe
database changes such as table creation operations or changes to
table data. It also contains events for statements that
potentially could have made changes (for example, a
DELETE
which matched no rows). The
binary log also contains information about how long each statement
took that updated data. The binary log has two important purposes:
For replication, the binary log is used on master replication servers as a record of the statements to be sent to slave servers. The master server sends the events contained in its binary log to its slaves, which execute those events to make the same data changes that were made on the master. See Section 16.2, “Replication Implementation”.
Certain data recovery operations require use of the binary log. After a backup has been restored, the events in the binary log that were recorded after the backup was made are re-executed. These events bring databases up to date from the point of the backup. See Section 6.5, “Point-in-Time (Incremental) Recovery Using the Binary Log”.
The binary log has replaced the old update log, which is no longer available as of MySQL 5.0. The binary log contains all information that is available in the update log in a more efficient format and in a manner that is transaction-safe. If you are using transactions, you must use the MySQL binary log for backups instead of the old update log.
Running a server with binary logging enabled makes performance about 1% slower. However, the benefits of the binary log in allowing you to set up replication and for restore operations generally outweigh this minor performance decrement.
For information about server options and variables affecting the operation of binary logging, see Section 16.1.2.4, “Binary Log Options and Variables”.
The binary log is not used for statements such as
SELECT
or
SHOW
that do not modify data. If
you want to log all statements (for example, to identify a problem
query), use the general query log. See
Section 5.2.2, “The General Query Log”.
The binary log should be protected because logged statements might contain passwords. See Section 5.3.2.1, “Administrator Guidelines for Password Security”.
MySQL Enterprise. The binary log can also be used to track significant DDL events. Analyzing the binary log in this way is an integral part of the MySQL Enterprise Monitor. For more information, see http://www.mysql.com/products/enterprise/advisors.html.
To enable the binary log, start the server with the
--log-bin[=
option. If no base_name
]base_name
value is given,
the default name is the value of the pid-file
option (which by default is the name of host machine) followed by
-bin
. If the basename is given, the server
writes the file in the data directory unless the basename is given
with a leading absolute path name to specify a different
directory. It is recommended that you specify a basename; see
Additional Known Issues, for the reason.
From MySQL 5.0.41 through 5.0.52, “mysql” was used
when no base_name
was specified. Also
in these versions, a path given as part of the
--log-bin
options was treated as
absolute rather than relative. The previous behaviors were
restored in MySQL 5.0.54. (See Bug#28603 and Bug#28597.)
If you supply an extension in the log name (for example,
--log-bin=
),
the extension is silently removed and ignored.
base_name.extension
mysqld appends a numeric extension to the
binary log basename to generate binary log file names. The number
increases each time the server creates a new log file, thus
creating an ordered series of files. The server creates a new file
in the series each time it starts or flushes the logs. The server
also creates a new binary log file automatically after the current
log's size reaches
max_binlog_size
. A binary log
file may become larger than
max_binlog_size
if you are using
large transactions because a transaction is written to the file in
one piece, never split between files.
To keep track of which binary log files have been used,
mysqld also creates a binary log index file
that contains the names of all used binary log files. By default,
this has the same basename as the binary log file, with the
extension '.index'
. You can change the name of
the binary log index file with the
--log-bin-index[=
option. You should not manually edit this file while
mysqld is running; doing so would confuse
mysqld.
file_name
]
The term “binary log file” generally denotes an individual numbered file containing database events. The term “binary log” collectively denotes the set of numbered binary log files plus the index file.
The server evaluates the
--binlog-do-db
and
--binlog-ignore-db
options in the
same way as it does the
--replicate-do-db
and
--replicate-ignore-db
options. For
information about how this is done, see
Section 16.2.3.1, “Evaluation of Database-Level Replication and Binary Logging Options”.
A replication slave server by default does not write to its own
binary log any data modifications that are received from the
replication master. To log these modifications, start the slave
with the --log-slave-updates
option
in addition to the --log-bin
option
(see Section 16.1.2.3, “Replication Slave Options and Variables”).
You can delete all binary log files with the
RESET MASTER
statement, or a subset
of them with PURGE BINARY LOGS
. See
Section 12.4.6.5, “RESET
Syntax”, and Section 12.5.1.1, “PURGE BINARY LOGS
Syntax”.
If you are using replication, you should not delete old binary log
files on the master until you are sure that no slave still needs
to use them. For example, if your slaves never run more than three
days behind, once a day you can execute mysqladmin
flush-logs on the master and then remove any logs that
are more than three days old. You can remove the files manually,
but it is preferable to use PURGE BINARY
LOGS
, which also safely updates the binary log index
file for you (and which can take a date argument). See
Section 12.5.1.1, “PURGE BINARY LOGS
Syntax”.
A client that has the SUPER
privilege can disable binary logging of its own statements by
using a SET sql_log_bin=0
statement. See
Section 5.1.4, “Session System Variables”.
You can display the contents of binary log files with the mysqlbinlog utility. This can be useful when you want to reprocess statements in the log for a recovery operation. For example, you can update a MySQL server from the binary log as follows:
shell> mysqlbinlog log_file
| mysql -h server_name
mysqlbinlog also can be used to display replication slave relay log file contents because they are written using the same format as binary log files. For more information on the mysqlbinlog utility and how to use it, see Section 4.6.7, “mysqlbinlog — Utility for Processing Binary Log Files”. For more information about the binary log and recovery operations, see Section 6.5, “Point-in-Time (Incremental) Recovery Using the Binary Log”.
Binary logging is done immediately after a statement completes but before any locks are released or any commit is done. This ensures that the log is logged in execution order.
Updates to nontransactional tables are stored in the binary log
immediately after execution. In MySQL 5.0.53 and earlier versions
of MySQL 5.0, an
UPDATE
statement using a stored
function that modified a nontransactional table was not logged if
it failed, and an
INSERT ... ON
DUPLICATE KEY UPDATE
statement that encountered a
duplicate key constraint — but did not actually change any
data — was not logged. Beginning with MySQL 5.0.54, both of
these statements are written to the binary log. (Bug#23333)
Within an uncommitted transaction, all updates
(UPDATE
,
DELETE
, or
INSERT
) that change transactional
tables such as BDB
or InnoDB
tables are cached until a COMMIT
statement is received by the server. At that point,
mysqld writes the entire transaction to the
binary log before the COMMIT
is
executed. When the thread that handles the transaction starts, it
allocates a buffer of
binlog_cache_size
to buffer
statements. If a statement is bigger than this, the thread opens a
temporary file to store the transaction. The temporary file is
deleted when the thread ends.
The Binlog_cache_use
status
variable shows the number of transactions that used this buffer
(and possibly a temporary file) for storing statements. The
Binlog_cache_disk_use
status
variable shows how many of those transactions actually had to use
a temporary file. These two variables can be used for tuning
binlog_cache_size
to a large
enough value that avoids the use of temporary files.
The max_binlog_cache_size
system
variable (default 4GB, which is also the maximum) can be used to
restrict the total size used to cache a multiple-statement
transaction. If a transaction is larger than this many bytes, it
fails and rolls back. The minimum value is 4096.
Modifications to nontransactional tables cannot be rolled back. If
a transaction that is rolled back includes modifications to
nontransactional tables, the entire transaction is logged with a
ROLLBACK
statement at the end to ensure that the modifications to those
tables are replicated.
If you are using the binary log and row based logging, concurrent
inserts are converted to normal inserts for CREATE ...
SELECT
or
INSERT ...
SELECT
statement. This is done to ensure that you can
re-create an exact copy of your tables by applying the log during
a backup operation. If you are using statement-based logging, the
original statement is written to the log.
The binary log format has some known limitations that can affect recovery from backups. See Section 16.4.1, “Replication Features and Issues”.
Binary logging for stored programs is done as described in Section 18.5, “Binary Logging of Stored Programs”.
Note that the binary log format differs in MySQL 5.0 from previous versions of MySQL, due to enhancements in replication. See Section 16.4.2, “Replication Compatibility Between MySQL Versions”.
Writes to the binary log file and binary log index file are
handled in the same way as writes to MyISAM
tables. See Section B.5.4.3, “How MySQL Handles a Full Disk”.
By default, the binary log is not synchronized to disk at each
write. So if the operating system or machine (not only the MySQL
server) crashes, there is a chance that the last statements of the
binary log are lost. To prevent this, you can make the binary log
be synchronized to disk after every N
writes to the binary log, with the
sync_binlog
system variable. See
Section 5.1.3, “Server System Variables”. 1 is the safest value
for sync_binlog
, but also the
slowest. Even with sync_binlog
set to 1, there is still the chance of an inconsistency between
the table content and binary log content in case of a crash. For
example, if you are using InnoDB
tables and the
MySQL server processes a COMMIT
statement, it writes the whole transaction to the binary log and
then commits this transaction into InnoDB
. If
the server crashes between those two operations, the transaction
is rolled back by InnoDB
at restart but still
exists in the binary log. This problem can be solved with the
--innodb_safe_binlog
option, which
adds consistency between the content of InnoDB
tables and the binary log. (Note:
--innodb_safe_binlog
is unneeded as
of MySQL 5.0; it was made obsolete by the introduction of XA
transaction support.)
For this option to provide a greater degree of safety, the MySQL
server should also be configured to synchronize the binary log and
the InnoDB
logs to disk at every transaction.
The InnoDB
logs are synchronized by default,
and sync_binlog=1
can be used to synchronize
the binary log. The effect of this option is that at restart after
a crash, after doing a rollback of transactions, the MySQL server
cuts rolled back InnoDB
transactions from the
binary log. This ensures that the binary log reflects the exact
data of InnoDB
tables, and so, that the slave
remains in synchrony with the master (not receiving a statement
which has been rolled back).
Note that --innodb_safe_binlog
can
be used even if the MySQL server updates other storage engines
than InnoDB
. Only statements and transactions
that affect InnoDB
tables are subject to
removal from the binary log at InnoDB
's crash
recovery. If the MySQL server discovers at crash recovery that the
binary log is shorter than it should have been, it lacks at least
one successfully committed InnoDB
transaction.
This should not happen if sync_binlog=1
and the
disk/file system do an actual sync when they are requested to
(some don't), so the server prints an error message The
binary log <name> is shorter than its expected
size
. In this case, this binary log is not correct and
replication should be restarted from a fresh snapshot of the
master's data.
For MySQL 5.0.46, the session values of the following system variables are written to the binary log and honored by the replication slave when parsing the binary log:
User Comments
Add your own comment.