You can use the mysqld options and system variables that are described in this section to affect the operation of the binary log as well as to control which statements are written to the binary log. For additional information about the binary log, see Section 5.2.4, “The Binary Log”. For additional information about using MySQL server options and system variables, see Section 5.1.2, “Server Command Options”, and Section 5.1.4, “Server System Variables”.
Startup options used with binary logging. The following list describes startup options for enabling and configuring the binary log. System variables used with binary logging are discussed later in this section.
Command-Line Format --binlog-row-event-max-size=#
Option-File Format binlog-row-event-max-size
Permitted Values Platform Bit Size 32
Type numeric
Default 1024
Range 256-4294967295
Permitted Values Platform Bit Size 64
Type numeric
Default 1024
Range 256-18446744073709547520
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 1024. See Section 17.1.2, “Replication Formats”.
Command-Line Format --log-bin
Option-File Format log-bin
Variable Name log_bin
Variable Scope Global Dynamic Variable No Permitted Values Type file name
Default OFF
Enable binary logging. The server logs all statements that change data to the binary log, which is used for backup and replication. See Section 5.2.4, “The Binary Log”.
The option value, if given, is the basename for the log sequence. The server creates binary log files in sequence by adding a numeric suffix to the basename. It is recommended that you specify a basename (see Section C.5.8, “Known Issues in MySQL”, for the reason). Otherwise, MySQL uses
as the basename.host_name
-binSetting this option causes the
log_bin
system variable to be set toON
(or1
), and not to the basename. This is a known issue; see Bug#19614 for more information.Command-Line Format --log-bin-index=name
Option-File Format log-bin-index
Permitted Values Type file name
Default OFF
The index file for binary log file names. See Section 5.2.4, “The Binary Log”. If you omit the file name, and if you did not specify one with
--log-bin
, MySQL uses
as the file name.host_name
-bin.index--log-bin-trust-function-creators[={0|1}]
Command-Line Format --log-bin-trust-function-creators
Option-File Format log-bin-trust-function-creators
Option Sets Variable Yes, log_bin_trust_function_creators
Variable Name log_bin_trust_function_creators
Variable Scope Global Dynamic Variable Yes Permitted Values Type boolean
Default FALSE
This option sets the corresponding
log_bin_trust_function_creators
system variable. If no argument is given, the option sets the variable to 1.log_bin_trust_function_creators
affects how MySQL enforces restrictions on stored function and trigger creation. See Section 19.7, “Binary Logging of Stored Programs”.
Statement selection options. The options in the following list affect which statements are written to the binary log, and thus sent by a replication master server to its slaves. There are also options for slave servers that control which statements received from the master should be executed or ignored. For details, see Section 17.1.3.3, “Replication Slave Options and Variables”.
This option affects binary logging in a manner similar to the way that
--replicate-do-db
affects replication.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
--replicate-do-db
depend on whether statement-based or row-based replication is in use. You should keep in mind that the format used to log a given statement may not necessarily be the same as that indicated by the value ofbinlog_format
. For example, DDL statements such asCREATE TABLE
andALTER TABLE
are always logged as statements, without regard to the logging format in effect, so the following statement-based rules for--binlog-do-db
always apply in determining whether or not the statement is logged.Statement-based logging. Only those statements are written to the binary log where the default database (that is, the one selected by
USE
) isdb_name
. To specify more than one database, use this option multiple times, once for each database; however, doing so does not cause cross-database statements such asUPDATE
to be logged while a different database (or no database) is selected.some_db.some_table
SET foo='bar'WarningTo specify multiple databases you must use multiple instances of this option. Because database names can contain commas, the list will be treated as the name of a single database if you supply a comma-separated list.
An example of what does not work as you might expect when using statement-based logging: If the server is started with
--binlog-do-db=sales
and you issue the following statements, theUPDATE
statement is not logged:USE prices; UPDATE sales.january SET amount=amount+1000;
The main reason for this “just check the default database” behavior is that it is difficult from the statement alone to know whether it should be replicated (for example, if you are using multiple-table
DELETE
statements or multiple-tableUPDATE
statements that act across multiple databases). It is also faster to check only the default database rather than all databases if there is no need.Another case which may not be self-evident occurs when a given database is replicated even though it was not specified when setting the option. If the server is started with
--binlog-do-db=sales
, the followingUPDATE
statement is logged even thoughprices
was not included when setting--binlog-do-db
:USE sales; UPDATE prices.discounts SET percentage = percentage + 10;
Because
sales
is the default database when theUPDATE
statement is issued, theUPDATE
is logged.Row-based logging. Logging is restricted to database
db_name
. Only changes to tables belonging todb_name
are logged; the default database has no effect on this. Suppose that the server is started with--binlog-do-db=sales
and row-based logging is in effect, and then the following statements are executed:USE prices; UPDATE sales.february SET amount=amount+100;
The changes to the
february
table in thesales
database are logged in accordance with theUPDATE
statement; this occurs whether or not theUSE
statement was issued. However, when using the row-based logging format and--binlog-do-db=sales
, changes made by the followingUPDATE
are not logged:USE prices; UPDATE prices.march SET amount=amount-25;
Even if the
USE prices
statement were changed toUSE sales
, theUPDATE
statement's effects would still not be written to the binary log.Another important difference in
--binlog-do-db
handling for statement-based logging as opposed to the row-based logging occurs with regard to statements that refer to multiple databases. Suppose that the server is started with--binlog-do-db=db1
, and the following statements are executed:USE db1; UPDATE db1.table1 SET col1 = 10, db2.table2 SET col2 = 20;
If you are using statement-based logging, the updates to both tables are written to the binary log. However, when using the row-based format, only the changes to
table1
are logged;table2
is in a different database, so it is not changed by theUPDATE
. Now suppose that, instead of theUSE db1
statement, aUSE db4
statement had been used:USE db4; UPDATE db1.table1 SET col1 = 10, db2.table2 SET col2 = 20;
In this case, the
UPDATE
statement is not written to the binary log when using statement-based logging. However, when using row-based logging, the change totable1
is logged, but not that totable2
—in other words, only changes to tables in the database named by--binlog-do-db
are logged, and the choice of default database has no effect on this behavior.This option affects binary logging in a manner similar to the way that
--replicate-ignore-db
affects replication.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
--replicate-ignore-db
depend on whether statement-based or row-based replication is in use. You should keep in mind that the format used to log a given statement may not necessarily be the same as that indicated by the value ofbinlog_format
. For example, DDL statements such asCREATE TABLE
andALTER TABLE
are always logged as statements, without regard to the logging format in effect, so the following statement-based rules for--binlog-ignore-db
always apply in determining whether or not the statement is logged.Statement-based logging. Tells the server to not log any statement where the default database (that is, the one selected by
USE
) isdb_name
.Row-based format. Tells the server not to log updates to any tables in the database
db_name
. The current database has no effect.When using statement-based logging, the following example does not work as you might expect. Suppose that the server is started with
--binlog-ignore-db=sales
and you issue the following statements:USE prices; UPDATE sales.january SET amount=amount+1000;
The
UPDATE
statement is logged in such a case because--binlog-ignore-db
applies only to the default database (determined by theUSE
statement). Because thesales
database was specified explicitly in the statement, the statement has not been filtered. However, when using row-based logging, theUPDATE
statement's effects are not written to the binary log, which means that no changes to thesales.january
table are logged; in this instance,--binlog-ignore-db=sales
causes all changes made to tables in the master's copy of thesales
database to be ignored for purposes of binary logging.To specify more than one database to ignore, use this option multiple times, once for each database. Because database names can contain commas, the list will be treated as the name of a single database if you supply a comma-separated list.
You should not use this option if you are using cross-database updates and you do not want these updates to be logged.
Testing and debugging options. The following binary log options are used in replication testing and debugging. They are not intended for use in normal operations.
Command-Line Format --max-binlog-dump-events=#
Option-File Format max-binlog-dump-events
Permitted Values Type numeric
Default 0
This option is used internally by the MySQL test suite for replication testing and debugging.
Command-Line Format --sporadic-binlog-dump-fail
Option-File Format sporadic-binlog-dump-fail
Permitted Values Type boolean
Default FALSE
This option is used internally by the MySQL test suite for replication testing and debugging.
System variables used with the binary log.
The following list describes system variables for controlling
binary logging. They can be set at server startup and some of
them can be changed at runtime using
SET
.
Server options used to control binary logging are listed earlier
in this section.
Command-Line Format --binlog_cache_size=#
Option-File Format binlog_cache_size
Option Sets Variable Yes, binlog_cache_size
Variable Name binlog_cache_size
Variable Scope Global Dynamic Variable Yes Permitted Values Platform Bit Size 32
Type numeric
Default 32768
Range 4096-4294967295
Permitted Values Platform Bit Size 64
Type numeric
Default 32768
Range 4096-18446744073709547520
The size of the cache to hold changes to the binary log during a transaction. A binary log cache is allocated for each client if the server supports any transactional storage engines and if the server has the binary log enabled (
--log-bin
option). If you often use large transactions, you can increase this cache size to get better performance. TheBinlog_cache_use
andBinlog_cache_disk_use
status variables can be useful for tuning the size of this variable. See Section 5.2.4, “The Binary Log”.In MySQL 5.5.3, a separate binary log cache (the binary log statement cache) was introduced for nontransactional statements and in MySQL 5.5.3 through 5.5.8, this variable sets.the size for both caches. This means that, in these MySQL versions, the total memory used for these caches is double the value set for
binlog_cache_size
.Begining with MySQL 5.5.9,
binlog_cache_size
sets the size for the transaction cache only, and the size of the statement cache is governed by thebinlog_stmt_cache_size
system variable.binlog_direct_non_transactional_updates
Version Introduced 5.5.2 Command-Line Format --binlog_direct_non_transactional_updates[=value]
Option-File Format binlog_direct_non_transactional_updates
Option Sets Variable Yes, binlog_direct_non_transactional_updates
Variable Name binlog_direct_non_transactional_updates
Variable Scope Global, Session Dynamic Variable Yes Permitted Values Type boolean
Default OFF
Due to concurrency issues, a slave can become inconsistent when a transaction contains updates to both transactional and non-transactional tables. MySQL tries to preserve causality among these statements by writing non-transactional statements to the transaction cache, which is flushed upon commit. However, problems arise when modifications done to nontransactional tables on behalf of a transaction become immediately visible to other connections because these changes may not be written immediately into the binary log.
Beginning with MySQL 5.5.2, the
binlog_direct_non_transactional_updates
variable offers one possible workaround to this issue. By default, this variable is disabled. Enablingbinlog_direct_non_transactional_updates
causes updates to nontransactional tables to be written directly to the binary log, rather than to the transaction cache.binlog_direct_non_transactional_updates
works only for statements that are replicated using the statement-based binary logging format; that is, it works only when the value ofbinlog_format
isSTATEMENT
, or whenbinlog_format
isMIXED
and a given statement is being replicated using the statement-based format. This variable has no effect when the binary log format isROW
, or whenbinlog_format
is set toMIXED
and a given statement is replicated using the row-based format.ImportantBefore enabling this variable, you must make certain that there are no dependencies between transactional and nontransactional tables; an example of such a dependency would be the statement
INSERT INTO myisam_table SELECT * FROM innodb_table
. Otherwise, such statements are likely to cause the slave to diverge from the master.Beginning with MySQL 5.5.5, this variable has no effect when the binary log format is
ROW
orMIXED
. (Bug#51291)Command-Line Format --binlog-format=format
Option-File Format binlog-format=format
Option Sets Variable Yes, binlog_format
Variable Name binlog_format
Variable Scope Global, Session Dynamic Variable Yes Permitted Values Type enumeration
Default STATEMENT
Valid Values ROW
,STATEMENT
,MIXED
This variable sets the binary logging format, and can be any one of
STATEMENT
,ROW
, orMIXED
. See Section 17.1.2, “Replication Formats”.binlog_format
is set by the--binlog-format
option at startup, or by thebinlog_format
variable at runtime.In MySQL 5.5, the default format is
STATEMENT
.You must have the
SUPER
privilege to set either the global or sessionbinlog_format
value.The rules governing when changes to this variable take effect and how long the effect lasts are the same as for other MySQL server system variables. See Section 12.4.4, “
SET
Syntax”, for more information.When
MIXED
is specified, statement-based replication is used, except for cases where only row-based replication is guaranteed to lead to proper results. For example, this happens when statements contain user-defined functions (UDF) or theUUID()
function. An exception to this rule is thatMIXED
always uses statement-based replication for stored functions and triggers.There are exceptions when you cannot switch the replication format at runtime:
From within a stored function or a trigger.
If the session is currently in row-based replication mode and has open temporary tables.
Beginning with MySQL 5.5.3, within a transaction. (Bug#47863)
Trying to switch the format in those cases results in an error.
The binary log format affects the behavior of the following server options:
These effects are discussed in detail in the descriptions of the individual options.
Command-Line Format --max_binlog_cache_size=#
Option-File Format max_binlog_cache_size
Option Sets Variable Yes, max_binlog_cache_size
Variable Name max_binlog_cache_size
Variable Scope Global Dynamic Variable Yes Permitted Values Type numeric
Default 18446744073709547520
Range 4096-18446744073709547520
If a transaction requires more than this many bytes of memory, the server generates a Multi-statement transaction required more than 'max_binlog_cache_size' bytes of storage error. The minimum value is 4096. The maximum and default values are 4GB on 32-bit platforms and 16PB (petabytes) on 64-bit platforms.
In MySQL 5.5.3, a separate binary log cache (the binary log statement cache) was introduced for nontransactional statements and in MySQL 5.5.3 through 5.5.8, this variable sets.the upper limit for both caches. This means that, in these MySQL versions, the effective maximum for these caches is double the value set for
max_binlog_cache_size
.Begining with MySQL 5.5.9,
max_binlog_cache_size
sets the size for the transaction cache only, and the upper limit for the statement cache is governed by themax_binlog_stmt_cache_size
system variable.Version Introduced 5.5.9 Command-Line Format --max_binlog_stmt_cache_size=#
Option-File Format max_binlog_stmt_cache_size
Option Sets Variable Yes, max_binlog_stmt_cache_size
Variable Name max_binlog_stmt_cache_size
Variable Scope Global Dynamic Variable Yes Permitted Values Type numeric
Default 18446744073709547520
Range 4096-18446744073709547520
If nontransaction statements within a transaction require more than this many bytes of memory, the server generates an error. The minimum value is 4096. The maximum and default values are 4GB on 32-bit platforms and 16PB (petabytes) on 64-bit platforms.
In MySQL 5.5.3, a separate binary log cache (the binary log statement cache) was introduced for nontransactional statements and in MySQL 5.5.3 through 5.5.8, this variable sets.the upper limit for both caches. This means that, in these MySQL versions, the effective maximum for these caches is double the value set for
max_binlog_cache_size
.Begining with MySQL 5.5.9,
max_binlog_stmt_cache_size
sets the size for the transaction cache only, and the upper limit for the transaction cache is governed exclusively by themax_binlog_cache_size
system variable.Command-Line Format --max_binlog_size=#
Option-File Format max_binlog_size
Option Sets Variable Yes, max_binlog_size
Variable Name max_binlog_size
Variable Scope Global Dynamic Variable Yes Permitted Values Type numeric
Default 1073741824
Range 4096-1073741824
If a write to the binary log causes the current log file size to exceed the value of this variable, the server rotates the binary logs (closes the current file and opens the next one). The minimum value is 4096 bytes. The maximum and default value is 1GB.
A transaction is written in one chunk to the binary log, so it is never split between several binary logs. Therefore, if you have big transactions, you might see binary log files larger than
max_binlog_size
.If
max_relay_log_size
is 0, the value ofmax_binlog_size
applies to relay logs as well.Version Introduced 5.5.9 Command-Line Format --binlog_stmt_cache_size=#
Option-File Format binlog_stmt_cache_size
Option Sets Variable Yes, binlog_stmt_cache_size
Variable Name binlog_stmt_cache_size
Variable Scope Global Dynamic Variable Yes Permitted Values Platform Bit Size 32
Type numeric
Default 32768
Range 4096-4294967295
Permitted Values Platform Bit Size 64
Type numeric
Default 32768
Range 4096-18446744073709547520
Beginning with MySQL 5.5.9, this variable determines the size of the cache for the binary log to hold nontransactional statements issued during a transaction. In MySQL 5.5.3 and later, separate binary log transaction and statement caches are allocated for each client if the server supports any transactional storage engines and if the server has the binary log enabled (
--log-bin
option). If you often use large nontransactional statements during transactions, you can increase this cache size to get more performance. TheBinlog_stmt_cache_use
andBinlog_stmt_cache_disk_use
status variables can be useful for tuning the size of this variable. See Section 5.2.4, “The Binary Log”.In MySQL 5.5.3 through 5.5.8, the size for both caches is set using
binlog_cache_size
. This means that, in these MySQL versions, the total memory used for these caches is double the value set forbinlog_cache_size
. Begining with MySQL 5.5.9,binlog_cache_size
sets the size for the transaction cache only.Command-Line Format --sync-binlog=#
Option-File Format sync_binlog
Option Sets Variable Yes, sync_binlog
Variable Name sync_binlog
Variable Scope Global Dynamic Variable Yes Permitted Values Platform Bit Size 32
Type numeric
Default 0
Range 0-4294967295
Permitted Values Platform Bit Size 64
Type numeric
Default 0
Range 0-18446744073709547520
If the value of this variable is greater than 0, the MySQL server synchronizes its binary log to disk (using
fdatasync()
) after everysync_binlog
writes to the binary log. There is one write to the binary log per statement if autocommit is enabled, and one write per transaction otherwise. The default value ofsync_binlog
is 0, which does no synchronizing to disk—in this case, the server relies on the operating system to flush the binary log's contents from to time as for any other file. A value of 1 is the safest choice because in the event of a crash you lose at most one statement or transaction from the binary log. However, it is also the slowest choice (unless the disk has a battery-backed cache, which makes synchronization very fast).