Documentation Home
MySQL 5.6 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 31.4Mb
PDF (A4) - 31.5Mb
PDF (RPM) - 30.0Mb
EPUB - 7.7Mb
HTML Download (TGZ) - 7.5Mb
HTML Download (Zip) - 7.5Mb
HTML Download (RPM) - 6.5Mb
Eclipse Doc Plugin (TGZ) - 8.2Mb
Eclipse Doc Plugin (Zip) - 10.1Mb
Man Pages (TGZ) - 180.8Kb
Man Pages (Zip) - 292.0Kb
Info (Gzip) - 2.8Mb
Info (Zip) - 2.8Mb
Excerpts from this Manual

17.1.4.4 Binary Log Options and Variables

Startup Options Used with Binary Logging

System Variables Used with Binary Logging

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.4.4, “The Binary Log”. For additional information about using MySQL server options and system variables, see Section 5.1.3, “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.

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

    Command-Line Format--binlog-row-event-max-size=#
    Permitted Values (32-bit platforms, <= 5.6.5)Typeinteger
    Default1024
    Min Value256
    Max Value4294967295
    Permitted Values (32-bit platforms, >= 5.6.6)Typeinteger
    Default8192
    Min Value256
    Max Value4294967295
    Permitted Values (64-bit platforms, <= 5.6.5)Typeinteger
    Default1024
    Min Value256
    Max Value18446744073709551615
    Permitted Values (64-bit platforms, >= 5.6.6)Typeinteger
    Default8192
    Min Value256
    Max Value18446744073709551615

    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 8192 as of MySQL 5.6.6 and 1024 before that. See Section 17.1.2, “Replication Formats”.

  • --log-bin[=base_name]

    Command-Line Format--log-bin
    System VariableNamelog_bin
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name

    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.4.4, “The Binary Log”.

    The option value, if given, is the base name for the log sequence. The server creates binary log files in sequence by adding a numeric suffix to the base name. It is recommended that you specify a base name (see Section B.5.7, “Known Issues in MySQL”, for the reason). Otherwise, MySQL uses host_name-bin as the base name.

    In MySQL 5.6.5 and later, when the server reads an entry from the index file, it checks whether the entry contains a relative path, and if it does, the relative part of the path is replaced with the absolute path set using the --log-bin option. An absolute path remains unchanged; in such a case, the index must be edited manually to enable the new path or paths to be used. Previous to MySQL 5.6.5, manual intervention was required whenever relocating the binary log or relay log files. (Bug #11745230, Bug #12133)

    Setting this option causes the log_bin system variable to be set to ON (or 1), and not to the base name. Beginning with MySQL 5.6.2, the binary log filename (with path) is available as the log_bin_basename system variable.

  • --log-bin-index[=file_name]

    Command-Line Format--log-bin-index=file_name
    Permitted ValuesTypefile name

    The index file for binary log file names. See Section 5.4.4, “The Binary Log”. If you omit the file name, and if you did not specify one with --log-bin, MySQL uses host_name-bin.index as the file name.

  • --log-bin-trust-function-creators[={0|1}]

    Command-Line Format--log-bin-trust-function-creators
    System VariableNamelog_bin_trust_function_creators
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultFALSE

    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 20.7, “Binary Logging of Stored Programs”.

  • --log-bin-use-v1-row-events[={0|1}]

    Introduced5.6.6
    Command-Line Format--log-bin-use-v1-row-events[={0|1}]
    System VariableNamelog_bin_use_v1_row_events
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted Values (>= 5.6.6)Typeboolean
    Default0

    Version 2 binary log row events are available beginning with MySQL 5.6.6; however, Version 2 events cannot be read by previous MySQL Server releases. Setting this option to 1 causes mysqld to write the binary log using Version 1 logging events, which is the only version of binary log events used in previous releases, and thus produce binary logs that can be read by older slaves. Setting --log-bin-use-v1-row-events to 0 (the default) causes mysqld to use Version 2 binary log events.

    The value used for this option can be obtained from the read-only log_bin_use_v1_row_events system variable.

    --log-bin-use-v1-row-events is chiefly of interest when setting up replication conflict detection and resolution using NDB$EPOCH_TRANS() as the conflict detection function, which requires Version 2 binary log row events. Thus, this option and --ndb-log-transaction-id are not compatible.

    For more information, see Section 18.6.11, “MySQL Cluster Replication Conflict Resolution”.

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.4.3, “Replication Slave Options and Variables”.

  • --binlog-do-db=db_name

    Command-Line Format--binlog-do-db=name
    Permitted ValuesTypestring

    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 of binlog_format. For example, DDL statements such as CREATE TABLE and ALTER 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) is db_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 as UPDATE some_db.some_table SET foo='bar' to be logged while a different database (or no database) is selected.

    Warning

    To 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, the UPDATE 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-table UPDATE 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 following UPDATE statement is logged even though prices was not included when setting --binlog-do-db:

              
    USE sales;
    UPDATE prices.discounts SET percentage = percentage + 10;
    

    Because sales is the default database when the UPDATE statement is issued, the UPDATE is logged.

    Row-based logging.  Logging is restricted to database db_name. Only changes to tables belonging to db_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 the sales database are logged in accordance with the UPDATE statement; this occurs whether or not the USE statement was issued. However, when using the row-based logging format and --binlog-do-db=sales, changes made by the following UPDATE are not logged:

    USE prices;
    UPDATE prices.march SET amount=amount-25;
    

    Even if the USE prices statement were changed to USE sales, the UPDATE 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 the UPDATE. Now suppose that, instead of the USE db1 statement, a USE 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 to table1 is logged, but not that to table2—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.

  • --binlog-ignore-db=db_name

    Command-Line Format--binlog-ignore-db=name
    Permitted ValuesTypestring

    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 of binlog_format. For example, DDL statements such as CREATE TABLE and ALTER 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) is db_name.

    Prior to MySQL 5.6.12, this option caused any statements containing fully qualified table names not to be logged if there was no default database specified (that is, when SELECT DATABASE() returned NULL). In MySQL 5.6.12 and later, when there is no default database, no --binlog-ignore-db options are applied, and such statements are always logged. (Bug #11829838, Bug #60188)

    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 the USE statement). Because the sales database was specified explicitly in the statement, the statement has not been filtered. However, when using row-based logging, the UPDATE statement's effects are not written to the binary log, which means that no changes to the sales.january table are logged; in this instance, --binlog-ignore-db=sales causes all changes made to tables in the master's copy of the sales 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.

Checksum options.  Beginning with MySQL 5.6.2, MySQL supports reading and writing of binary log checksums. These are enabled using the two options listed here:

  • --binlog-checksum={NONE|CRC32}

    Introduced5.6.2
    Command-Line Format--binlog-checksum=type
    Permitted Values (<= 5.6.5)Typestring
    DefaultNONE
    Valid ValuesNONE
    CRC32
    Permitted Values (>= 5.6.6)Typestring
    DefaultCRC32
    Valid ValuesNONE
    CRC32

    Enabling this option causes the master to write checksums for events written to the binary log. Set to NONE to disable, or the name of the algorithm to be used for generating checksums; currently, only CRC32 checksums are supported. As of MySQL 5.6.6, CRC32 is the default.

    This option was added in MySQL 5.6.2.

  • --master-verify-checksum={0|1}

    Introduced5.6.2
    Command-Line Format--master-verify-checksum=name
    Permitted ValuesTypeboolean
    DefaultOFF

    Enabling this option causes the master to verify events from the binary log using checksums, and to stop with an error in the event of a mismatch. Disabled by default.

    This option was added in MySQL 5.6.2.

To control reading of checksums by the slave (from the relay) log, use the --slave-sql-verify-checksum option.

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.

  • --max-binlog-dump-events=N

    Command-Line Format--max-binlog-dump-events=#
    Permitted ValuesTypeinteger
    Default0

    This option is used internally by the MySQL test suite for replication testing and debugging.

  • --sporadic-binlog-dump-fail

    Command-Line Format--sporadic-binlog-dump-fail
    Permitted ValuesTypeboolean
    DefaultFALSE

    This option is used internally by the MySQL test suite for replication testing and debugging.

  • --binlog-rows-query-log-events

    Introduced5.6.2
    Command-Line Format--binlog-rows-query-log-events
    Permitted ValuesTypeboolean
    DefaultFALSE

    Added in MySQL 5.6.2, this option enables binlog_rows_query_log_events. Must be set to OFF (the default) when generating logs for a MySQL 5.6.1 or earlier slave server or version of mysqlbinlog.

System Variables Used with Binary Logging

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. For information about the sql_log_bin and sql_log_off variables, see Section 5.1.4, “Server System Variables”.

  • binlog_cache_size

    Command-Line Format--binlog_cache_size=#
    System VariableNamebinlog_cache_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default32768
    Min Value4096
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default32768
    Min Value4096
    Max Value18446744073709551615

    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. The Binlog_cache_use and Binlog_cache_disk_use status variables can be useful for tuning the size of this variable. See Section 5.4.4, “The Binary Log”.

    binlog_cache_size sets the size for the transaction cache only; the size of the statement cache is governed by the binlog_stmt_cache_size system variable.

  • binlog_checksum

    Introduced5.6.2
    System VariableNamebinlog_checksum
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (<= 5.6.5)Typestring
    DefaultNONE
    Valid ValuesNONE
    CRC32
    Permitted Values (>= 5.6.6)Typestring
    DefaultCRC32
    Valid ValuesNONE
    CRC32

    When enabled, this variable causes the master to write a checksum for each event in the binary log. binlog_checksum supports the values NONE (disabled) and CRC32. The default is CRC32 as of MySQL 5.6.6, NONE before that.

    When binlog_checksum is disabled (value NONE), the server verifies that it is writing only complete events to the binary log by writing and checking the event length (rather than a checksum) for each event.

    Changing the value of this variable causes the binary log to be rotated; checksums are always written to an entire binary log file, and never to only part of one.

    This variable was added in MySQL 5.6.2.

    In MySQL 5.6.6 and later, setting this variable on the master to a value unrecognized by the slave causes the slave to set its own binlog_checksum value to NONE, and to stop replication with an error. (Bug #13553750, Bug #61096) If backward compatibility with older slaves is a concern, you may want to set the value explicitly to NONE.

  • binlog_direct_non_transactional_updates

    Command-Line Format--binlog_direct_non_transactional_updates[=value]
    System VariableNamebinlog_direct_non_transactional_updates
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultOFF

    Due to concurrency issues, a slave can become inconsistent when a transaction contains updates to both transactional and nontransactional tables. MySQL tries to preserve causality among these statements by writing nontransactional 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.

    The binlog_direct_non_transactional_updates variable offers one possible workaround to this issue. By default, this variable is disabled. Enabling binlog_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 of binlog_format is STATEMENT, or when binlog_format is MIXED and a given statement is being replicated using the statement-based format. This variable has no effect when the binary log format is ROW, or when binlog_format is set to MIXED and a given statement is replicated using the row-based format.

    Important

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

    In MySQL 5.6, this variable has no effect when the binary log format is ROW or MIXED. (Bug #51291)

  • binlog_error_action

    Introduced5.6.22
    Command-Line Format--binlog_error_action[=value]
    System VariableNamebinlog_error_action
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeenumeration
    DefaultIGNORE_ERROR
    Valid ValuesIGNORE_ERROR
    ABORT_SERVER

    Controls what happens when the server cannot write to the binary log, which can cause the master's log to become inconsistent and replication slaves to lose synchronization. Previous releases used the name binlogging_impossible_mode.

    In MySQL 5.6, the default for binlog_error_action is IGNORE_ERROR, meaning the server logs the error, halts logging, and continues performing updates; this is to provide backward compatibility with older versions of the MySQL Server. Setting this variable to ABORT_SERVER makes the server halt logging and shut down whenever it cannot write to the binary log; this is the recommended setting, particularly in complex replication environments.

  • binlog_format

    Command-Line Format--binlog-format=format
    System VariableNamebinlog_format
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeenumeration
    DefaultSTATEMENT
    Valid ValuesROW
    STATEMENT
    MIXED
    Permitted Values (>= 5.6.10-ndb-7.3.1)Typeenumeration
    DefaultMIXED
    Valid ValuesROW
    STATEMENT
    MIXED

    This variable sets the binary logging format, and can be any one of STATEMENT, ROW, or MIXED. See Section 17.1.2, “Replication Formats”. binlog_format is set by the --binlog-format option at startup, or by the binlog_format variable at runtime.

    Note

    While you can change the logging format at runtime, it is not recommended that you change it while replication is ongoing. This is due in part to the fact that slaves do not honor the master's binlog_format setting; a given MySQL Server can change only its own logging format.

    In MySQL 5.6, the default format is STATEMENT. Exception: In MySQL Cluster NDB 7.3 and later, the default is MIXED; statement-based replication is not supported for MySQL Cluster.

    You must have the SUPER privilege to set either the global or session binlog_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 13.7.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 the UUID() function. An exception to this rule is that MIXED 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.

    • From within a transaction.

    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.

  • binlogging_impossible_mode

    Introduced5.6.20
    Deprecated5.6.22
    Command-Line Format--binlogging_impossible_mode[=value]
    System VariableNamebinlogging_impossible_mode
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeenumeration
    DefaultIGNORE_ERROR
    Valid ValuesIGNORE_ERROR
    ABORT_SERVER

    This option is deprecated and will be removed in a future MySQL release. Use the renamed binlog_error_action to control what happens when the server cannot write to the binary log.

  • binlog_max_flush_queue_time

    Introduced5.6.6
    System VariableNamebinlog_max_flush_queue_time
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default0
    Min Value0
    Max Value100000

    How long in microseconds to keep reading transactions from the flush queue before proceeding with the group commit (and syncing the log to disk, if sync_binlog is greater than 0). If the value is 0 (the default), there is no timeout and the server keeps reading new transactions until the queue is empty.

    Normally, binlog_max_flush_queue_time can remain set to 0. If the server processes a large number of connections (for example, 100 or more) and many short transactions with low-latency requirements, it may be useful to set the value larger than 0 to force more frequent flushes to disk.

    This variable was added in MySQL 5.6.6.

  • binlog_order_commits

    Introduced5.6.6
    System VariableNamebinlog_order_commits
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultON

    If this variable is enabled (the default), transactions are committed in the same order they are written to the binary log. If disabled, transactions may be committed in parallel. In some cases, disabling this variable might produce a performance increment.

    This variable was added in MySQL 5.6.6.

  • binlog_row_image

    Introduced5.6.2
    Command-Line Format--binlog-row-image=image_type
    System VariableNamebinlog_row_image=image_type
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeenumeration
    Defaultfull
    Valid Valuesfull (Log all columns)
    minimal (Log only changed columns, and columns needed to identify rows)
    noblob (Log all columns, except for unneeded BLOB and TEXT columns)

    In MySQL row-based replication, each row change event contains two images, a before image whose columns are matched against when searching for the row to be updated, and an after image containing the changes. Normally, MySQL logs full rows (that is, all columns) for both the before and after images. However, it is not strictly necessary to include every column in both images, and we can often save disk, memory, and network usage by logging only those columns which are actually required.

    Note

    When deleting a row, only the before image is logged, since there are no changed values to propagate following the deletion. When inserting a row, only the after image is logged, since there is no existing row to be matched. Only when updating a row are both the before and after images required, and both written to the binary log.

    For the before image, it is necessary only that the minimum set of columns required to uniquely identify rows is logged. If the table containing the row has a primary key, then only the primary key column or columns are written to the binary log. Otherwise, if the table has a unique key all of whose columns are NOT NULL, then only the columns in the unique key need be logged. (If the table has neither a primary key nor a unique key without any NULL columns, then all columns must be used in the before image, and logged.) In the after image, it is necessary to log only the columns which have actually changed.

    In MySQL 5.6, you can cause the server to log full or minimal rows using the binlog_row_image system variable. This variable actually takes one of three possible values, as shown in the following list:

    • full: Log all columns in both the before image and the after image.

    • minimal: Log only those columns in the before image that are required to identify the row to be changed; log only those columns in the after image that are actually changed.

    • noblob: Log all columns (same as full), except for BLOB and TEXT columns that are not required to identify rows, or that have not changed.

    Note

    This variable is not supported by MySQL Cluster; setting it has no effect on the logging of NDB tables. (Bug #16316828)

    The default value is full. In MySQL 5.5 and earlier, full row images are always used for both before images and after images. If you need to replicate from a MySQL 5.6 (or later) master to a slave running a previous version of MySQL, the master should always use this value.

    When using minimal or noblob, deletes and updates are guaranteed to work correctly for a given table if and only if the following conditions are true for both the source and destination tables:

    • All columns must be present and in the same order; each column must use the same data type as its counterpart in the other table.

    • The tables must have identical primary key definitions.

    (In other words, the tables must be identical with the possible exception of indexes that are not part of the tables' primary keys.)

    If these conditions are not met, it is possible that the primary key column values in the destination table may prove insufficient to provide a unique match for a delete or update. In this event, no warning or error is issued; the master and slave silently diverge, thus breaking consistency.

    Setting this variable has no effect when the binary logging format is STATEMENT. When binlog_format is MIXED, the setting for binlog_row_image is applied to changes that are logged using row-based format, but this setting no effect on changes logged as statements.

    Setting binlog_row_image on either the global or session level does not cause an implicit commit; this means that this variable can be changed while a transaction is in progress without affecting the transaction.

  • binlog_rows_query_log_events

    Introduced5.6.2
    System VariableNamebinlog_rows_query_log_events
    Variable ScopeGlobal, Session
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultFALSE

    The binlog_rows_query_log_events system variable affects row-based logging only. When enabled, it causes a MySQL 5.6.2 or later server to write informational log events such as row query log events into its binary log. This information can be used for debugging and related purposes; such as obtaining the original query issued on the master when it cannot be reconstructed from the row updates.

    These events are normally ignored by MySQL 5.6.2 and later programs reading the binary log and so cause no issues when replicating or restoring from backup. This is not true for a mysqld or mysqlbinlog from MySQL 5.6.1 or earlier: When the older version of the program reading the log encounters an informational log event, it fails, and stops reading at that point. To make the binary log readable by slave replication MySQL servers and other readers (for example, mysqlbinlog) from a MySQL 5.6.1 or earlier distribution, binlog_rows_query_log_events must be disabled during logging.

  • binlog_stmt_cache_size

    Introduced5.6.1
    Command-Line Format--binlog_stmt_cache_size=#
    System VariableNamebinlog_stmt_cache_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default32768
    Min Value4096
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default32768
    Min Value4096
    Max Value18446744073709551615

    This variable determines the size of the cache for the binary log to hold nontransactional statements issued during a transaction. 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 better performance. The Binlog_stmt_cache_use and Binlog_stmt_cache_disk_use status variables can be useful for tuning the size of this variable. See Section 5.4.4, “The Binary Log”.

    The binlog_cache_size system variable sets the size for the transaction cache.

  • log_bin

    System VariableNamelog_bin
    Variable ScopeGlobal
    Dynamic VariableNo

    Whether the binary log is enabled. If the --log-bin option is used, then the value of this variable is ON; otherwise it is OFF. This variable reports only on the status of binary logging (enabled or disabled); it does not actually report the value to which --log-bin is set.

    See Section 5.4.4, “The Binary Log”.

  • log_bin_basename

    Introduced5.6.2
    System VariableNamelog_bin_basename
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name
    Defaultdatadir + '/' + hostname + '-bin'

    Holds the name and complete path to the binary log file. Unlike the log_bin system variable, log_bin_basename reflects the name set with the --log-bin server option.

    The log_bin_basename system variable was added in MySQL 5.6.2.

  • log_bin_index

    Introduced5.6.4
    System VariableNamelog_bin_index
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypefile name

    The index file for binary log file names.

    The log_bin_index system variable was added in MySQL 5.6.4.

  • log_bin_use_v1_row_events

    Introduced5.6.6
    Command-Line Format--log-bin-use-v1-row-events[={0|1}]
    System VariableNamelog_bin_use_v1_row_events
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted Values (>= 5.6.6)Typeboolean
    Default0

    Shows whether Version 2 binary logging, available beginning with MySQL 5.6.6, is in use. A value of 1 shows that the server is writing the binary log using Version 1 logging events (the only version of binary log events used in MySQL 5.6.5 and previous MySQL Server releases), and thus producing a binary log that can be read by older slaves. 0 indicates that Version 2 binary log events are in use.

    This variable is read-only. To switch between Version 1 and Version 2 binary event binary logging, it is necessary to restart mysqld with the --log-bin-use-v1-row-events option.

    Other than when performing upgrades of MySQL Cluster Replication, --log-bin-use-v1-events is chiefly of interest when setting up replication conflict detection and resolution using NDB$EPOCH_TRANS(), which requires Version 2 binary row event logging. Thus, this option and --ndb-log-transaction-id are not compatible.

    Note

    MySQL Cluster NDB 7.3 and later use Version 2 binary log row events by default. You should keep this mind when planning upgrades or downgrades, and for setups using MySQL Cluster Replication.

    For more information, see Section 18.6.11, “MySQL Cluster Replication Conflict Resolution”.

  • log_slave_updates

    Command-Line Format--log-slave-updates
    System VariableNamelog_slave_updates
    Variable ScopeGlobal
    Dynamic VariableNo
    Permitted ValuesTypeboolean
    DefaultFALSE

    Whether updates received by a slave server from a master server should be logged to the slave's own binary log. Binary logging must be enabled on the slave for this variable to have any effect. See Section 17.1.4, “Replication and Binary Logging Options and Variables”.

  • master_verify_checksum

    Introduced5.6.2
    System VariableNamemaster_verify_checksum
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeboolean
    DefaultOFF

    Enabling this variable causes the master to examine checksums when reading from the binary log. master_verify_checksum is disabled by default; in this case, the master uses the event length from the binary log to verify events, so that only complete events are read from the binary log.

    This variable was added in MySQL 5.6.2.

  • max_binlog_cache_size

    Command-Line Format--max_binlog_cache_size=#
    System VariableNamemax_binlog_cache_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default18446744073709551615
    Min Value4096
    Max Value18446744073709551615

    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 possible value is 16EB (exabytes). The maximum recommended value is 4GB; this is due to the fact that MySQL currently cannot work with binary log positions greater than 4GB.

    Note

    Prior to MySQL 5.6.7, 64-bit Windows platforms truncated the stored value for this variable to 4G, even when it was set to a greater value (Bug #13961678).

    max_binlog_cache_size sets the size for the transaction cache only; the upper limit for the statement cache is governed by the max_binlog_stmt_cache_size system variable.

    In MySQL 5.6, the visibility to sessions of max_binlog_cache_size matches that of the binlog_cache_size system variable; in other words, changing its value effects only new sessions that are started after the value is changed.

  • max_binlog_size

    Command-Line Format--max_binlog_size=#
    System VariableNamemax_binlog_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default1073741824
    Min Value4096
    Max Value1073741824

    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 of max_binlog_size applies to relay logs as well.

  • max_binlog_stmt_cache_size

    Introduced5.6.1
    Command-Line Format--max_binlog_stmt_cache_size=#
    System VariableNamemax_binlog_stmt_cache_size
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted ValuesTypeinteger
    Default18446744073709547520
    Min Value4096
    Max Value18446744073709547520

    If nontransactional 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 16EB (exabytes) on 64-bit platforms.

    Note

    Prior to MySQL 5.6.7, 64-bit Windows platforms truncated the stored value for this variable to 4G, even when it was set to a greater value (Bug #13961678).

    max_binlog_stmt_cache_size sets the size for the statement cache only; the upper limit for the transaction cache is governed exclusively by the max_binlog_cache_size system variable.

  • sync_binlog

    Command-Line Format--sync-binlog=#
    System VariableNamesync_binlog
    Variable ScopeGlobal
    Dynamic VariableYes
    Permitted Values (32-bit platforms)Typeinteger
    Default0
    Min Value0
    Max Value4294967295
    Permitted Values (64-bit platforms)Typeinteger
    Default0
    Min Value0
    Max Value4294967295

    If the value of this variable is greater than 0, the MySQL server synchronizes its binary log to disk (using fdatasync()) after sync_binlog commit groups are written to the binary log. The default value of sync_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 time 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 commit group from the binary log. However, it is also the slowest choice (unless the disk has a battery-backed cache, which makes synchronization very fast).


User Comments
Sign Up Login You must be logged in to post a comment.