Documentation Home
MySQL 9.2 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 40.8Mb
PDF (A4) - 40.9Mb
Man Pages (TGZ) - 259.7Kb
Man Pages (Zip) - 366.9Kb
Info (Gzip) - 4.1Mb
Info (Zip) - 4.1Mb


19.1.6.2 Replication Source Options and Variables

This section describes the server options and system variables that you can use on replication source servers. You can specify the options either on thecommand line or in anoption file. You can specify system variable values usingSET.

On the source and each replica, you must set theserver_id system variable to establish a unique replication ID. For each server, you should pick a unique positive integer in the range from 1 to 232 − 1, and each ID must be different from every other ID in use by any other source or replica in the replication topology. Example:server-id=3.

For options used on the source for controlling binary logging, seeSection 19.1.6.4, “Binary Logging Options and Variables”.

Startup Options for Replication Source Servers

The following list describes startup options for controlling replication source servers. Replication-related system variables are discussed later in this section.

System Variables Used on Replication Source Servers

The following system variables are used for or by replication source servers:

  • auto_increment_increment

    Command-Line Format--auto-increment-increment=#
    System Variableauto_increment_increment
    ScopeGlobal, Session
    DynamicYes
    SET_VAR Hint AppliesYes
    TypeInteger
    Default Value1
    Minimum Value1
    Maximum Value65535

    auto_increment_increment andauto_increment_offset are intended for use with circular (source-to-source) replication, and can be used to control the operation ofAUTO_INCREMENT columns. Both variables have global and session values, and each can assume an integer value between 1 and 65,535 inclusive. Setting the value of either of these two variables to 0 causes its value to be set to 1 instead. Attempting to set the value of either of these two variables to an integer greater than 65,535 or less than 0 causes its value to be set to 65,535 instead. Attempting to set the value ofauto_increment_increment orauto_increment_offset to a noninteger value produces an error, and the actual value of the variable remains unchanged.

    Note

    auto_increment_increment is also supported for use withNDB tables.

    When Group Replication is started on a server, the value ofauto_increment_increment is changed to the value ofgroup_replication_auto_increment_increment, which defaults to 7, and the value ofauto_increment_offset is changed to the server ID. The changes are reverted when Group Replication is stopped. These changes are only made and reverted ifauto_increment_increment andauto_increment_offset each have their default value of 1. If their values have already been modified from the default, Group Replication does not alter them. These system variables are also not modified when Group Replication is in single-primary mode, where only one server writes.

    auto_increment_increment andauto_increment_offset affectAUTO_INCREMENT column behavior as follows:

    • auto_increment_increment controls the interval between successive column values. For example:

      mysql> SHOW VARIABLES LIKE 'auto_inc%';+--------------------------+-------+| Variable_name            | Value |+--------------------------+-------+| auto_increment_increment | 1     || auto_increment_offset    | 1     |+--------------------------+-------+2 rows in set (0.00 sec)mysql> CREATE TABLE autoinc1    -> (col INT NOT NULL AUTO_INCREMENT PRIMARY KEY);  Query OK, 0 rows affected (0.04 sec)mysql> SET @@auto_increment_increment=10;Query OK, 0 rows affected (0.00 sec)mysql> SHOW VARIABLES LIKE 'auto_inc%';+--------------------------+-------+| Variable_name            | Value |+--------------------------+-------+| auto_increment_increment | 10    || auto_increment_offset    | 1     |+--------------------------+-------+2 rows in set (0.01 sec)mysql> INSERT INTO autoinc1 VALUES (NULL), (NULL), (NULL), (NULL);Query OK, 4 rows affected (0.00 sec)Records: 4  Duplicates: 0  Warnings: 0mysql> SELECT col FROM autoinc1;+-----+| col |+-----+|   1 ||  11 ||  21 ||  31 |+-----+4 rows in set (0.00 sec)
    • auto_increment_offset determines the starting point for theAUTO_INCREMENT column value. Consider the following, assuming that these statements are executed during the same session as the example given in the description forauto_increment_increment:

      mysql> SET @@auto_increment_offset=5;Query OK, 0 rows affected (0.00 sec)mysql> SHOW VARIABLES LIKE 'auto_inc%';+--------------------------+-------+| Variable_name            | Value |+--------------------------+-------+| auto_increment_increment | 10    || auto_increment_offset    | 5     |+--------------------------+-------+2 rows in set (0.00 sec)mysql> CREATE TABLE autoinc2    -> (col INT NOT NULL AUTO_INCREMENT PRIMARY KEY);Query OK, 0 rows affected (0.06 sec)mysql> INSERT INTO autoinc2 VALUES (NULL), (NULL), (NULL), (NULL);Query OK, 4 rows affected (0.00 sec)Records: 4  Duplicates: 0  Warnings: 0mysql> SELECT col FROM autoinc2;+-----+| col |+-----+|   5 ||  15 ||  25 ||  35 |+-----+4 rows in set (0.02 sec)

      When the value ofauto_increment_offset is greater than that ofauto_increment_increment, the value ofauto_increment_offset is ignored.

    If either of these variables is changed, and then new rows inserted into a table containing anAUTO_INCREMENT column, the results may seem counterintuitive because the series ofAUTO_INCREMENT values is calculated without regard to any values already present in the column, and the next value inserted is the least value in the series that is greater than the maximum existing value in theAUTO_INCREMENT column. The series is calculated like this:

    auto_increment_offset +N ×auto_increment_increment

    whereN is a positive integer value in the series [1, 2, 3, ...]. For example:

    mysql> SHOW VARIABLES LIKE 'auto_inc%';+--------------------------+-------+| Variable_name            | Value |+--------------------------+-------+| auto_increment_increment | 10    || auto_increment_offset    | 5     |+--------------------------+-------+2 rows in set (0.00 sec)mysql> SELECT col FROM autoinc1;+-----+| col |+-----+|   1 ||  11 ||  21 ||  31 |+-----+4 rows in set (0.00 sec)mysql> INSERT INTO autoinc1 VALUES (NULL), (NULL), (NULL), (NULL);Query OK, 4 rows affected (0.00 sec)Records: 4  Duplicates: 0  Warnings: 0mysql> SELECT col FROM autoinc1;+-----+| col |+-----+|   1 ||  11 ||  21 ||  31 ||  35 ||  45 ||  55 ||  65 |+-----+8 rows in set (0.00 sec)

    The values shown forauto_increment_increment andauto_increment_offset generate the series 5 +N × 10, that is, [5, 15, 25, 35, 45, ...]. The highest value present in thecol column prior to theINSERT is 31, and the next available value in theAUTO_INCREMENT series is 35, so the inserted values forcol begin at that point and the results are as shown for theSELECT query.

    It is not possible to restrict the effects of these two variables to a single table; these variables control the behavior of allAUTO_INCREMENT columns inall tables on the MySQL server. If the global value of either variable is set, its effects persist until the global value is changed or overridden by setting the session value, or untilmysqld is restarted. If the local value is set, the new value affectsAUTO_INCREMENT columns for all tables into which new rows are inserted by the current user for the duration of the session, unless the values are changed during that session.

    The default value ofauto_increment_increment is 1. SeeSection 19.5.1.1, “Replication and AUTO_INCREMENT”.

  • auto_increment_offset

    Command-Line Format--auto-increment-offset=#
    System Variableauto_increment_offset
    ScopeGlobal, Session
    DynamicYes
    SET_VAR Hint AppliesYes
    TypeInteger
    Default Value1
    Minimum Value1
    Maximum Value65535

    This variable has a default value of 1. If it is left with its default value, and Group Replication is started on the server in multi-primary mode, it is changed to the server ID. For more information, see the description forauto_increment_increment.

    Note

    auto_increment_offset is also supported for use withNDB tables.

  • immediate_server_version

    System Variableimmediate_server_version
    ScopeSession
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeInteger
    Default Value999999
    Minimum Value0
    Maximum Value999999

    For internal use by replication. This session system variable holds the MySQL Server release number of the server that is the immediate source in a replication topology (for example,90200 for a MySQL 9.2.0 server instance). If this immediate server is at a release that does not support the session system variable, the value of the variable is set to 0 (UNKNOWN_SERVER_VERSION).

    The value of the variable is replicated from a source to a replica. With this information the replica can correctly process data originating from a source at an older release, by recognizing where syntax changes or semantic changes have occurred between the releases involved and handling these appropriately. The information can also be used in a Group Replication environment where one or more members of the replication group is at a newer release than the others. The value of the variable can be viewed in the binary log for each transaction (as part of theGtid_log_event, orAnonymous_gtid_log_event if GTIDs are not in use on the server), and could be helpful in debugging cross-version replication issues.

    Setting the session value of this system variable is a restricted operation. The session user must have either theREPLICATION_APPLIER privilege (seeSection 19.3.3, “Replication Privilege Checks”), or privileges sufficient to set restricted session variables (seeSection 7.1.9.1, “System Variable Privileges”). However, note that the variable is not intended for users to set; it is set automatically by the replication infrastructure.

  • original_server_version

    System Variableoriginal_server_version
    ScopeSession
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeInteger
    Default Value999999
    Minimum Value0
    Maximum Value999999

    For internal use by replication. This session system variable holds the MySQL Server release number of the server where a transaction was originally committed (for example,90200 for a MySQL 9.2.0 server instance). If this original server is at a release that does not support the session system variable, the value of the variable is set to 0 (UNKNOWN_SERVER_VERSION). Note that when a release number is set by the original server, the value of the variable is reset to 0 if the immediate server or any other intervening server in the replication topology does not support the session system variable, and so does not replicate its value.

    The value of the variable is set and used in the same ways as for theimmediate_server_version system variable. If the value of the variable is the same as that for theimmediate_server_version system variable, only the latter is recorded in the binary log, with an indicator that the original server version is the same.

    In a Group Replication environment, view change log events, which are special transactions queued by each group member when a new member joins the group, are tagged with the server version of the group member queuing the transaction. This ensures that the server version of the original donor is known to the joining member. Because the view change log events queued for a particular view change have the same GTID on all members, for this case only, instances of the same GTID might have a different original server version.

    Setting the session value of this system variable is a restricted operation. The session user must have either theREPLICATION_APPLIER privilege (seeSection 19.3.3, “Replication Privilege Checks”), or privileges sufficient to set restricted session variables (seeSection 7.1.9.1, “System Variable Privileges”). However, note that the variable is not intended for users to set; it is set automatically by the replication infrastructure.

  • rpl_semi_sync_master_enabled

    Command-Line Format--rpl-semi-sync-master-enabled[={OFF|ON}]
    System Variablerpl_semi_sync_master_enabled
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeBoolean
    Default ValueOFF

    Deprecated synonym forrpl_semi_sync_source_enabled.

  • rpl_semi_sync_master_timeout

    Command-Line Format--rpl-semi-sync-master-timeout=#
    System Variablerpl_semi_sync_master_timeout
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeInteger
    Default Value10000
    Minimum Value0
    Maximum Value4294967295
    Unitmilliseconds

    Deprecated synonym forrpl_semi_sync_source_timeout.

  • rpl_semi_sync_master_trace_level

    Command-Line Format--rpl-semi-sync-master-trace-level=#
    System Variablerpl_semi_sync_master_trace_level
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeInteger
    Default Value32
    Minimum Value0
    Maximum Value4294967295

    Deprecated synonym forrpl_semi_sync_source_trace_level.

  • rpl_semi_sync_master_wait_for_slave_count

    Command-Line Format--rpl-semi-sync-master-wait-for-slave-count=#
    System Variablerpl_semi_sync_master_wait_for_slave_count
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeInteger
    Default Value1
    Minimum Value1
    Maximum Value65535

    Deprecated synonym forrpl_semi_sync_source_wait_for_replica_count.

  • rpl_semi_sync_master_wait_no_slave

    Command-Line Format--rpl-semi-sync-master-wait-no-slave[={OFF|ON}]
    System Variablerpl_semi_sync_master_wait_no_slave
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeBoolean
    Default ValueON

    Deprecated synonym forrpl_semi_sync_source_wait_no_replica.

  • rpl_semi_sync_master_wait_point

    Command-Line Format--rpl-semi-sync-master-wait-point=value
    System Variablerpl_semi_sync_master_wait_point
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeEnumeration
    Default ValueAFTER_SYNC
    Valid Values

    AFTER_SYNC

    AFTER_COMMIT

    Deprecated synonym forrpl_semi_sync_source_wait_point.

  • rpl_semi_sync_source_enabled

    Command-Line Format--rpl-semi-sync-source-enabled[={OFF|ON}]
    System Variablerpl_semi_sync_source_enabled
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeBoolean
    Default ValueOFF

    rpl_semi_sync_source_enabled is available when therpl_semi_sync_source (semisync_source.so library) plugin was installed on the replica to set up semisynchronous replication.

    rpl_semi_sync_source_enabled controls whether semisynchronous replication is enabled on the source server. To enable or disable the plugin, set this variable toON orOFF (or 1 or 0), respectively. The default isOFF.

  • rpl_semi_sync_source_timeout

    Command-Line Format--rpl-semi-sync-source-timeout=#
    System Variablerpl_semi_sync_source_timeout
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeInteger
    Default Value10000
    Minimum Value0
    Maximum Value4294967295
    Unitmilliseconds

    rpl_semi_sync_source_timeout is available when therpl_semi_sync_source (semisync_source.so library) plugin is installed on the replica.

    rpl_semi_sync_source_timeout controls how long the source waits on a commit for acknowledgment from a replica before timing out and reverting to asynchronous replication. The value is specified in milliseconds, and the default value is 10000 (10 seconds).

  • rpl_semi_sync_source_trace_level

    Command-Line Format--rpl-semi-sync-source-trace-level=#
    System Variablerpl_semi_sync_source_trace_level
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeInteger
    Default Value32
    Minimum Value0
    Maximum Value4294967295

    rpl_semi_sync_source_trace_level is available when therpl_semi_sync_source (semisync_source.so library) plugin is installed on the replica.

    rpl_semi_sync_source_trace_level specifies the semisynchronous replication debug trace level on the source server. Four levels are defined:

    • 1 = general level (for example, time function failures)

    • 16 = detail level (more verbose information)

    • 32 = net wait level (more information about network waits)

    • 64 = function level (information about function entry and exit)

  • rpl_semi_sync_source_wait_for_replica_count

    Command-Line Format--rpl-semi-sync-source-wait-for-replica-count=#
    System Variablerpl_semi_sync_source_wait_for_replica_count
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeInteger
    Default Value1
    Minimum Value1
    Maximum Value65535

    rpl_semi_sync_source_wait_for_replica_count is available when therpl_semi_sync_source (semisync_source.so library) plugin is installed on the replica to set up semisynchronous replication.

    rpl_semi_sync_source_wait_for_replica_count specifies the number of replica acknowledgments the source must receive per transaction before proceeding. By defaultrpl_semi_sync_source_wait_for_replica_count is1, meaning that semisynchronous replication proceeds after receiving a single replica acknowledgment. Performance is best for small values of this variable.

    For example, ifrpl_semi_sync_source_wait_for_replica_count is2, then 2 replicas must acknowledge receipt of the transaction before the timeout period configured byrpl_semi_sync_source_timeout for semisynchronous replication to proceed. If fewer replicas acknowledge receipt of the transaction during the timeout period, the source reverts to normal replication.

    Note

    This behavior also depends onrpl_semi_sync_source_wait_no_replica.

  • rpl_semi_sync_source_wait_no_replica

    Command-Line Format--rpl-semi-sync-source-wait-no-replica[={OFF|ON}]
    System Variablerpl_semi_sync_source_wait_no_replica
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeBoolean
    Default ValueON

    rpl_semi_sync_source_wait_no_replica is available when therpl_semi_sync_source (semisync_source.so library) plugin is installed on the replica.

    rpl_semi_sync_source_wait_no_replica controls whether the source waits for the timeout period configured byrpl_semi_sync_source_timeout to expire, even if the replica count drops to less than the number of replicas configured byrpl_semi_sync_source_wait_for_replica_count during the timeout period.

    When the value ofrpl_semi_sync_source_wait_no_replica isON (the default), it is permissible for the replica count to drop to less thanrpl_semi_sync_source_wait_for_replica_count during the timeout period. As long as enough replicas acknowledge the transaction before the timeout period expires, semisynchronous replication continues.

    When the value ofrpl_semi_sync_source_wait_no_replica isOFF, if the replica count drops to less than the number configured inrpl_semi_sync_source_wait_for_replica_count at any time during the timeout period configured byrpl_semi_sync_source_timeout, the source reverts to normal replication.

  • rpl_semi_sync_source_wait_point

    Command-Line Format--rpl-semi-sync-source-wait-point=value
    System Variablerpl_semi_sync_source_wait_point
    ScopeGlobal
    DynamicYes
    SET_VAR Hint AppliesNo
    TypeEnumeration
    Default ValueAFTER_SYNC
    Valid Values

    AFTER_SYNC

    AFTER_COMMIT

    rpl_semi_sync_source_wait_point is available when therpl_semi_sync_source (semisync_source.so library) plugin is installed on the replica.

    rpl_semi_sync_source_wait_point controls the point at which a semisynchronous replication source server waits for replica acknowledgment of transaction receipt before returning a status to the client that committed the transaction. These values are permitted:

    • AFTER_SYNC (the default): The source writes each transaction to its binary log and the replica, and syncs the binary log to disk. The source waits for replica acknowledgment of transaction receipt after the sync. Upon receiving acknowledgment, the source commits the transaction to the storage engine and returns a result to the client, which then can proceed.

    • AFTER_COMMIT: The source writes each transaction to its binary log and the replica, syncs the binary log, and commits the transaction to the storage engine. The source waits for replica acknowledgment of transaction receipt after the commit. Upon receiving acknowledgment, the source returns a result to the client, which then can proceed.

    The replication characteristics of these settings differ as follows:

    • WithAFTER_SYNC, all clients see the committed transaction at the same time: After it has been acknowledged by the replica and committed to the storage engine on the source. Thus, all clients see the same data on the source.

      In the event of source failure, all transactions committed on the source have been replicated to the replica (saved to its relay log). An unexpected exit of the source server and failover to the replica is lossless because the replica is up to date. Note, however, that the source cannot be restarted in this scenario and must be discarded, because its binary log might contain uncommitted transactions that would cause a conflict with the replica when externalized after binary log recovery.

    • WithAFTER_COMMIT, the client issuing the transaction gets a return status only after the server commits to the storage engine and receives replica acknowledgment. After the commit and before replica acknowledgment, other clients can see the committed transaction before the committing client.

      If something goes wrong such that the replica does not process the transaction, then in the event of an unexpected source server exit and failover to the replica, it is possible for such clients to see a loss of data relative to what they saw on the source.