Replication between Aurora and MySQL or between Aurora and another Aurora DB cluster (binary log replication) - Amazon Aurora

Replication between Aurora and MySQL or between Aurora and another Aurora DB cluster (binary log replication)

Because Amazon Aurora MySQL is compatible with MySQL, you can set up replication between a MySQL database and an Amazon Aurora MySQL DB cluster. This type of replication uses the MySQL binary log replication, also referred to as binlog replication. If you use binary log replication with Aurora, we recommend that your MySQL database run MySQL version 5.5 or later. You can set up replication where your Aurora MySQL DB cluster is the replication source or the replica. You can replicate with an Amazon RDS MySQL DB instance, a MySQL database external to Amazon RDS, or another Aurora MySQL DB cluster.

Note

You can't use binlog replication to or from certain types of Aurora DB clusters. In particular, binlog replication isn't available for Aurora Serverless v1 clusters. If the SHOW MASTER STATUS and SHOW SLAVE STATUS (Aurora MySQL version 2) or SHOW REPLICA STATUS (Aurora MySQL version 3) statement returns no output, check that the cluster you're using supports binlog replication.

In Aurora MySQL version 3, binary log replication doesn't replicate to the mysql system database. Passwords and accounts aren't replicated by binlog replication in Aurora MySQL version 3. Therefore, Data Control Language (DCL) statements such as CREATE USER, GRANT, and REVOKE aren't replicated.

You can also replicate with an RDS for MySQL DB instance or Aurora MySQL DB cluster in another AWS Region. When you're performing replication across AWS Regions, make sure that your DB clusters and DB instances are publicly accessible. If the Aurora MySQL DB clusters are in private subnets in your VPC, use VPC peering between the AWS Regions. For more information, see A DB cluster in a VPC accessed by an EC2 instance in a different VPC.

If you want to configure replication between an Aurora MySQL DB cluster and an Aurora MySQL DB cluster in another AWS Region, you can create an Aurora MySQL DB cluster as a read replica in a different AWS Region from the source DB cluster. For more information, see Replicating Amazon Aurora MySQL DB clusters across AWS Regions.

With Aurora MySQL version 2 and 3, you can replicate between Aurora MySQL and an external source or target that uses global transaction identifiers (GTIDs) for replication. Ensure that the GTID-related parameters in the Aurora MySQL DB cluster have settings that are compatible with the GTID status of the external database. To learn how to do this, see Using GTID-based replication for Amazon Aurora MySQL. In Aurora MySQL version 3.01 and higher, you can choose how to assign GTIDs to transactions that are replicated from a source that doesn't use GTIDs. For information about the stored procedure that controls that setting, see mysql.rds_assign_gtids_to_anonymous_transactions (Aurora MySQL version 3).

Warning

When you replicate between Aurora MySQL and MySQL, make sure that you use only InnoDB tables. If you have MyISAM tables that you want to replicate, you can convert them to InnoDB before setting up replication with the following command.

alter table <schema>.<table_name> engine=innodb, algorithm=copy;

Setting up replication with MySQL or another Aurora DB cluster

Setting up MySQL replication with Aurora MySQL involves the following steps, which are discussed in detail:

1. Turn on binary logging on the replication source

2. Retain binary logs on the replication source until no longer needed

3. Create a snapshot or dump of your replication source

4. Load the snapshot or dump into your replica target

5. Create a replication user on your replication source

6. Turn on replication on your replica target

7. Monitor your replica

1. Turn on binary logging on the replication source

Find instructions on how to turn on binary logging on the replication source for your database engine following.

2. Retain binary logs on the replication source until no longer needed

When you use MySQL binary log replication, Amazon RDS doesn't manage the replication process. As a result, you need to ensure that the binlog files on your replication source are retained until after the changes have been applied to the replica. This maintenance helps you to restore your source database in the event of a failure.

Use the following instructions to retain binary logs for your database engine.

3. Create a snapshot or dump of your replication source

You use a snapshot or dump of your replication source to load a baseline copy of your data onto your replica and then start replicating from that point on.

Use the following instructions to create a snapshot or dump of the replication source for your database engine.

4. Load the snapshot or dump into your replica target

If you plan to load data from a dump of a MySQL database that is external to Amazon RDS, then you might want to create an EC2 instance to copy the dump files to, and then load the data into your DB cluster or DB instance from that EC2 instance. Using this approach, you can compress the dump file(s) before copying them to the EC2 instance in order to reduce the network costs associated with copying data to Amazon RDS. You can also encrypt the dump file or files to secure the data as it is being transferred across the network.

Use the following instructions to load the snapshot or dump of your replication source into your replica target for your database engine.

5. Create a replication user on your replication source

Create a user ID on the source that is used solely for replication. The following example is for RDS for MySQL or external MySQL source databases.

mysql> CREATE USER 'repl_user'@'domain_name' IDENTIFIED BY 'password';

For Aurora MySQL source databases, the skip_name_resolve DB cluster parameter is set to 1 (ON) and can't be modified, so you must use an IP address for the host instead of a domain name. For more information, see skip_name_resolve in the MySQL documentation.

mysql> CREATE USER 'repl_user'@'IP_address' IDENTIFIED BY 'password';

The user requires the REPLICATION CLIENT and REPLICATION SLAVE privileges. Grant these privileges to the user.

If you need to use encrypted replication, require SSL connections for the replication user. For example, you can use one of the following statements to require SSL connections on the user account repl_user.

GRANT REPLICATION CLIENT, REPLICATION SLAVE ON *.* TO 'repl_user'@'IP_address';
GRANT USAGE ON *.* TO 'repl_user'@'IP_address' REQUIRE SSL;
Note

If REQUIRE SSL isn't included, the replication connection might silently fall back to an unencrypted connection.

6. Turn on replication on your replica target

Before you turn on replication, we recommend that you take a manual snapshot of the Aurora MySQL DB cluster or RDS for MySQL DB instance replica target. If a problem arises and you need to re-establish replication with the DB cluster or DB instance replica target, you can restore the DB cluster or DB instance from this snapshot instead of having to import the data into your replica target again.

Use the following instructions to turn on replication for your database engine.

If replication fails, it can result in a large increase in unintentional I/O on the replica, which can degrade performance. If replication fails or is no longer needed, you can run the mysql.rds_reset_external_master (Aurora MySQL version 2) or mysql.rds_reset_external_source (Aurora MySQL version 3) stored procedure to remove the replication configuration.

Setting a location to stop replication to a read replica

In Aurora MySQL version 3.04 and higher, you can start replication and then stop it at a specified binary log file location using the mysql.rds_start_replication_until (Aurora MySQL version 3) stored procedure.

To start replication to a read replica and stop replication at a specific location
  1. Using a MySQL client, connect to the replica Aurora MySQL DB cluster as the master user.

  2. Run the mysql.rds_start_replication_until (Aurora MySQL version 3) stored procedure.

    The following example initiates replication and replicates changes until it reaches location 120 in the mysql-bin-changelog.000777 binary log file. In a disaster recovery scenario, assume that location 120 is just before the disaster.

    call mysql.rds_start_replication_until( 'mysql-bin-changelog.000777', 120);

Replication stops automatically when the stop point is reached. The following RDS event is generated: Replication has been stopped since the replica reached the stop point specified by the rds_start_replication_until stored procedure.

If you use GTID-based replication, use the mysql.rds_start_replication_until_gtid (Aurora MySQL version 3) stored procedure instead of the mysql.rds_start_replication_until (Aurora MySQL version 3) stored procedure. For more information about GTID-based replication, see Using GTID-based replication for Amazon Aurora MySQL.

7. Monitor your replica

When you set up MySQL replication with an Aurora MySQL DB cluster, you must monitor failover events for the Aurora MySQL DB cluster when it is the replica target. If a failover occurs, then the DB cluster that is your replica target might be recreated on a new host with a different network address. For information on how to monitor failover events, see Working with Amazon RDS event notification.

You can also monitor how far the replica target is behind the replication source by connecting to the replica target and running the SHOW SLAVE STATUS (Aurora MySQL version 2) or SHOW REPLICA STATUS (Aurora MySQL version 3) command. In the command output, the Seconds Behind Master field tells you how far the replica target is behind the source.

Synchronizing passwords between replication source and target

When you change user accounts and passwords on the replication source using SQL statements, those changes are replicated to the replication target automatically.

If you use the AWS Management Console, the AWS CLI, or the RDS API to change the master password on the replication source, those changes are not automatically replicated to the replication target. If you want to synchronize the master user and master password between the source and target systems, you must make the same change on the replication target yourself.

Stopping replication between Aurora and MySQL or between Aurora and another Aurora DB cluster

To stop binary log replication with a MySQL DB instance, external MySQL database, or another Aurora DB cluster, follow these steps, discussed in detail following in this topic.

1. Stop binary log replication on the replica target

2. Turn off binary logging on the replication source

1. Stop binary log replication on the replica target

Use the following instructions to stop binary log replication for your database engine.

2. Turn off binary logging on the replication source

Use the instructions in the following table to turn off binary logging on the replication source for your database engine.

Using Amazon Aurora to scale reads for your MySQL database

You can use Amazon Aurora with your MySQL DB instance to take advantage of the read scaling capabilities of Amazon Aurora and expand the read workload for your MySQL DB instance. To use Aurora to scale reads for your MySQL DB instance, create an Amazon Aurora MySQL DB cluster and make it a read replica of your MySQL DB instance. This applies to an RDS for MySQL DB instance, or a MySQL database running external to Amazon RDS.

For information on creating an Amazon Aurora DB cluster, see Creating an Amazon Aurora DB cluster.

When you set up replication between your MySQL DB instance and your Amazon Aurora DB cluster, be sure to follow these guidelines:

  • Use the Amazon Aurora DB cluster endpoint address when you reference your Amazon Aurora MySQL DB cluster. If a failover occurs, then the Aurora Replica that is promoted to the primary instance for the Aurora MySQL DB cluster continues to use the DB cluster endpoint address.

  • Maintain the binlogs on your writer instance until you have verified that they have been applied to the Aurora Replica. This maintenance ensures that you can restore your writer instance in the event of a failure.

Important

When using self-managed replication, you're responsible for monitoring and resolving any replication issues that may occur. For more information, see Diagnosing and resolving lag between read replicas.

Note

The permissions required to start replication on an Aurora MySQL DB cluster are restricted and not available to your Amazon RDS master user. Therefore, you must use the mysql.rds_set_external_master (Aurora MySQL version 2) or mysql.rds_set_external_source (Aurora MySQL version 3) and mysql.rds_start_replication procedures to set up replication between your Aurora MySQL DB cluster and your MySQL DB instance.

Start replication between an external source instance and an Aurora MySQL DB cluster

  1. Make the source MySQL DB instance read-only:

    mysql> FLUSH TABLES WITH READ LOCK; mysql> SET GLOBAL read_only = ON;
  2. Run the SHOW MASTER STATUS command on the source MySQL DB instance to determine the binlog location. You receive output similar to the following example:

    File Position ------------------------------------ mysql-bin-changelog.000031 107 ------------------------------------
  3. Copy the database from the external MySQL DB instance to the Amazon Aurora MySQL DB cluster using mysqldump. For very large databases, you might want to use the procedure in Importing data to a MySQL or MariaDB DB instance with reduced downtime in the Amazon Relational Database Service User Guide.

    For Linux, macOS, or Unix:

    mysqldump \ --databases <database_name> \ --single-transaction \ --compress \ --order-by-primary \ -u local_user \ -p local_password | mysql \ --host aurora_cluster_endpoint_address \ --port 3306 \ -u RDS_user_name \ -p RDS_password

    For Windows:

    mysqldump ^ --databases <database_name> ^ --single-transaction ^ --compress ^ --order-by-primary ^ -u local_user ^ -p local_password | mysql ^ --host aurora_cluster_endpoint_address ^ --port 3306 ^ -u RDS_user_name ^ -p RDS_password
    Note

    Make sure that there is not a space between the -p option and the entered password.

    Use the --host, --user (-u), --port and -p options in the mysql command to specify the hostname, user name, port, and password to connect to your Aurora DB cluster. The host name is the DNS name from the Amazon Aurora DB cluster endpoint, for example, mydbcluster.cluster-123456789012.us-east-1.rds.amazonaws.com. You can find the endpoint value in the cluster details in the Amazon RDS Management Console.

  4. Make the source MySQL DB instance writeable again:

    mysql> SET GLOBAL read_only = OFF; mysql> UNLOCK TABLES;

    For more information on making backups for use with replication, see Backing up a source or replica by making it read only in the MySQL documentation.

  5. In the Amazon RDS Management Console, add the IP address of the server that hosts the source MySQL database to the VPC security group for the Amazon Aurora DB cluster. For more information on modifying a VPC security group, see Security groups for your VPC in the Amazon Virtual Private Cloud User Guide.

    You might also need to configure your local network to permit connections from the IP address of your Amazon Aurora DB cluster, so that it can communicate with your source MySQL instance. To find the IP address of the Amazon Aurora DB cluster, use the host command.

    host aurora_endpoint_address

    The host name is the DNS name from the Amazon Aurora DB cluster endpoint.

  6. Using the client of your choice, connect to the external MySQL instance and create a MySQL user to be used for replication. This account is used solely for replication and must be restricted to your domain to improve security. The following is an example.

    CREATE USER 'repl_user'@'mydomain.com' IDENTIFIED BY 'password';
  7. For the external MySQL instance, grant REPLICATION CLIENT and REPLICATION SLAVE privileges to your replication user. For example, to grant the REPLICATION CLIENT and REPLICATION SLAVE privileges on all databases for the 'repl_user' user for your domain, issue the following command.

    GRANT REPLICATION CLIENT, REPLICATION SLAVE ON *.* TO 'repl_user'@'mydomain.com' IDENTIFIED BY 'password';
  8. Take a manual snapshot of the Aurora MySQL DB cluster to be the read replica before setting up replication. If you need to reestablish replication with the DB cluster as a read replica, you can restore the Aurora MySQL DB cluster from this snapshot instead of having to import the data from your MySQL DB instance into a new Aurora MySQL DB cluster.

  9. Make the Amazon Aurora DB cluster the replica. Connect to the Amazon Aurora DB cluster as the master user and identify the source MySQL database as the replication master by using the mysql.rds_set_external_master (Aurora MySQL version 2) or mysql.rds_set_external_source (Aurora MySQL version 3) and mysql.rds_start_replication procedures.

    Use the master log file name and master log position that you determined in Step 2. The following is an example.

    For Aurora MySQL version 2: CALL mysql.rds_set_external_master ('mymasterserver.mydomain.com', 3306, 'repl_user', 'password', 'mysql-bin-changelog.000031', 107, 0); For Aurora MySQL version 3: CALL mysql.rds_set_external_source ('mymasterserver.mydomain.com', 3306, 'repl_user', 'password', 'mysql-bin-changelog.000031', 107, 0);
  10. On the Amazon Aurora DB cluster, call the mysql.rds_start_replication procedure to start replication.

    CALL mysql.rds_start_replication;

After you have established replication between your source MySQL DB instance and your Amazon Aurora DB cluster, you can add Aurora Replicas to your Amazon Aurora DB cluster. You can then connect to the Aurora Replicas to read scale your data. For information on creating an Aurora Replica, see Adding Aurora Replicas to a DB cluster.

Optimizing binary log replication

Following, you can learn how to optimize binary log replication performance and troubleshoot related issues in Aurora MySQL.

Tip

This discussion presumes that you are familiar with the MySQL binary log replication mechanism and how it works. For background information, see Replication Implementation in the MySQL documentation.

Multithreaded binary log replication (Aurora MySQL version 3)

With multithreaded binary log replication, a SQL thread reads events from the relay log and queues them up for SQL worker threads to apply. The SQL worker threads are managed by a coordinator thread. The binary log events are applied in parallel when possible.

When an Aurora MySQL instance is configured to use binary log replication, by default the replica instance uses single-threaded replication for Aurora MySQL versions lower than 3.04. To enable multithreaded replication, you update the replica_parallel_workers parameter to a value greater than zero in your custom parameter group.

For Aurora MySQL version 3.04 and higher, replication is multithreaded by default, with replica_parallel_workers set to 4. You can modify this parameter in your custom parameter group.

The following configuration options help you to fine-tune multithreaded replication. For usage information, see Replication and Binary Logging Options and Variables in the MySQL Reference Manual.

Optimal configuration depends on several factors. For example, performance for binary log replication is influenced by your database workload characteristics and the DB instance class the replica is running on. Thus, we recommend that you thoroughly test all changes to these configuration parameters before applying new parameter settings to a production instance:

  • binlog_group_commit_sync_delay

  • binlog_group_commit_sync_no_delay_count

  • binlog_transaction_dependency_history_size

  • binlog_transaction_dependency_tracking

  • replica_preserve_commit_order

  • replica_parallel_type

  • replica_parallel_workers

In Aurora MySQL version 3.06 and higher, you can improve performance for binary log replicas when replicating transactions for large tables with more than one secondary index. This feature introduces a thread pool to apply secondary index changes in parallel on a binlog replica. The feature is controlled by the aurora_binlog_replication_sec_index_parallel_workers DB cluster parameter, which controls the total number of parallel threads available to apply the secondary index changes. The parameter is set to 0 (disabled) by default. Enabling this feature doesn't require an instance restart. To enable this feature, stop ongoing replication, set the desired number of parallel worker threads, and then start replication again.

You can also use this parameter as a global variable, where n is the number of parallel worker threads:

SET global aurora_binlog_replication_sec_index_parallel_workers=n;

Optimizing binlog replication (Aurora MySQL 2.10 and higher)

In Aurora MySQL 2.10 and higher, Aurora automatically applies an optimization known as the binlog I/O cache to binary log replication. By caching the most recently committed binlog events, this optimization is designed to improve binlog dump thread performance while limiting the impact to foreground transactions on the binlog source instance.

Note

This memory used for this feature is independent of the MySQL binlog_cache setting.

This feature doesn't apply to Aurora DB instances that use the db.t2 and db.t3 instance classes.

You don't need to adjust any configuration parameters to turn on this optimization. In particular, if you adjust the configuration parameter aurora_binlog_replication_max_yield_seconds to a nonzero value in earlier Aurora MySQL versions, set it back to zero for Aurora MySQL 2.10 and higher.

The status variables aurora_binlog_io_cache_reads and aurora_binlog_io_cache_read_requests are available in Aurora MySQL 2.10 and higher. These status variables help you to monitor how often the data is read from the binlog I/O cache.

  • aurora_binlog_io_cache_read_requests shows the number of binlog I/O read requests from the cache.

  • aurora_binlog_io_cache_reads shows the number of binlog I/O reads that retrieve information from the cache.

The following SQL query computes the percentage of binlog read requests that take advantage of the cached information. In this case, the closer the ratio is to 100, the better it is.

mysql> SELECT (SELECT VARIABLE_VALUE FROM INFORMATION_SCHEMA.GLOBAL_STATUS WHERE VARIABLE_NAME='aurora_binlog_io_cache_reads') / (SELECT VARIABLE_VALUE FROM INFORMATION_SCHEMA.GLOBAL_STATUS WHERE VARIABLE_NAME='aurora_binlog_io_cache_read_requests') * 100 as binlog_io_cache_hit_ratio; +---------------------------+ | binlog_io_cache_hit_ratio | +---------------------------+ | 99.99847949080622 | +---------------------------+

The binlog I/O cache feature also includes new metrics related to the binlog dump threads. Dump threads are the threads that are created when new binlog replicas are connected to the binlog source instance.

The dump thread metrics are printed to the database log every 60 seconds with the prefix [Dump thread metrics]. The metrics include information for each binlog replica such as Secondary_id, Secondary_uuid, binlog file name, and the position that each replica is reading. The metrics also include Bytes_behind_primary representing the distance in bytes between replication source and replica. This metric measures the lag of the replica I/O thread. That figure is different from the lag of the replica SQL applier thread, which is represented by the seconds_behind_master metric on the binlog replica. You can determine whether binlog replicas are catching up to the source or falling behind by checking whether the distance decreases or increases.

Optimizing binlog replication (Aurora MySQL version 2 through 2.09)

To optimize binary log replication for Aurora MySQL, you adjust the following cluster-level optimization parameters. These parameters help you to specify the right balance between latency on the binlog source instance and replication lag.

  • aurora_binlog_use_large_read_buffer

  • aurora_binlog_read_buffer_size

  • aurora_binlog_replication_max_yield_seconds

Note

For MySQL 5.7-compatible clusters, you can use these parameters in Aurora MySQL version 2 through 2.09.*. In Aurora MySQL 2.10.0 and higher, these parameters are superseded by the binlog I/O cache optimization and you don't need to use them.

Overview of the large read buffer and max-yield optimizations

You might experience reduced binary log replication performance when the binary log dump thread accesses the Aurora cluster volume while the cluster processes a high number of transactions. You can use the parameters aurora_binlog_use_large_read_buffer, aurora_binlog_replication_max_yield_seconds, and aurora_binlog_read_buffer_size to help minimize this type of contention.

Suppose that you have a situation where aurora_binlog_replication_max_yield_seconds is set to greater than 0 and the current binlog file of the dump thread is active. In this case, the binary log dump thread waits up to a specified number of seconds for the current binlog file to be filled by transactions. This wait period avoids contention that can arise from replicating each binlog event individually. However, doing so increases the replica lag for binary log replicas. Those replicas can fall behind the source by the same number of seconds as the aurora_binlog_replication_max_yield_seconds setting.

The current binlog file means the binlog file that the dump thread is currently reading to perform replication. We consider that a binlog file is active when the binlog file is updating or open to be updated by incoming transactions. After Aurora MySQL fills up the active binlog file, MySQL creates and switches to a new binlog file. The old binlog file becomes inactive. It isn't updated by incoming transactions any longer.

Note

Before adjusting these parameters, measure your transaction latency and throughput over time. You might find that binary log replication performance is stable and has low latency even if there is occasional contention.

aurora_binlog_use_large_read_buffer

If this parameter is set to 1, Aurora MySQL optimizes binary log replication based on the settings of the parameters aurora_binlog_read_buffer_size and aurora_binlog_replication_max_yield_seconds. If aurora_binlog_use_large_read_buffer is 0, Aurora MySQL ignores the values of the aurora_binlog_read_buffer_size and aurora_binlog_replication_max_yield_seconds parameters.

aurora_binlog_read_buffer_size

Binary log dump threads with larger read buffer minimize the number of read I/O operations by reading more events for each I/O. The parameter aurora_binlog_read_buffer_size sets the read buffer size. The large read buffer can reduce binary log contention for workloads that generate a large amount of binlog data.

Note

This parameter only has an effect when the cluster also has the setting aurora_binlog_use_large_read_buffer=1.

Increasing the size of the read buffer doesn't affect the performance of binary log replication. Binary log dump threads don't wait for updating transactions to fill up the read buffer.

aurora_binlog_replication_max_yield_seconds

If your workload requires low transaction latency, and you can tolerate some replication lag, you can increase the aurora_binlog_replication_max_yield_seconds parameter. This parameter controls the maximum yield property of binary log replication in your cluster.

Note

This parameter only has an effect when the cluster also has the setting aurora_binlog_use_large_read_buffer=1.

Aurora MySQL recognizes any change to the aurora_binlog_replication_max_yield_seconds parameter value immediately. You don't need to restart the DB instance. However, when you turn on this setting, the dump thread only starts to yield when the current binlog file reaches its maximum size of 128 MB and is rotated to a new file.

Related parameters

Use the following DB cluster parameters to turn on binlog optimization.

Parameter Default Valid Values Description
aurora_binlog_use_large_read_buffer 1 0, 1 Switch for turning on the feature of replication improvement. When its value is 1, the binary log dump thread uses aurora_binlog_read_buffer_size for binary log replication; otherwise default buffer size (8K) is used. Not used in Aurora MySQL version 3.
aurora_binlog_read_buffer_size 5242880 8192-536870912 Read buffer size used by binary log dump thread when the parameter aurora_binlog_use_large_read_buffer is set to 1. Not used in Aurora MySQL version 3.
aurora_binlog_replication_max_yield_seconds 0 0-36000

For Aurora MySQL version 2.07.*, the maximum accepted value is 45. You can tune it to a higher value on 2.09 and later versions.

For version 2, this parameter works only when the parameter aurora_binlog_use_large_read_buffer is set to 1.

Enabling the max-yield mechanism for binary log replication

You can turn on the binary log replication max-yield optimization as follows. Doing so minimizes latency for transactions on the binlog source instance. However, you might experience higher replication lag.

To turn on the max-yield binlog optimization for an Aurora MySQL cluster
  1. Create or edit a DB cluster parameter group using the following parameter settings:

    • aurora_binlog_use_large_read_buffer: turn on with a value of ON or 1.

    • aurora_binlog_replication_max_yield_seconds: specify a value greater than 0.

  2. Associate the DB cluster parameter group with the Aurora MySQL cluster that works as the binlog source. To do so, follow the procedures in Working with parameter groups.

  3. Confirm that the parameter change takes effect. To do so, run the following query on the binlog source instance.

    SELECT @@aurora_binlog_use_large_read_buffer, @@aurora_binlog_replication_max_yield_seconds;

    Your output should be similar to the following.

    +---------------------------------------+-----------------------------------------------+ | @@aurora_binlog_use_large_read_buffer | @@aurora_binlog_replication_max_yield_seconds | +---------------------------------------+-----------------------------------------------+ | 1 | 45 | +---------------------------------------+-----------------------------------------------+

Turning off the binary log replication max-yield optimization

You can turn off the binary log replication max-yield optimization as follows. Doing so minimizes replication lag. However, you might experience higher latency for transactions on the binlog source instance.

To turn off the max-yield optimization for an Aurora MySQL cluster
  1. Make sure that the DB cluster parameter group associated with the Aurora MySQL cluster has aurora_binlog_replication_max_yield_seconds set to 0. For more information about setting configuration parameters using parameter groups, see Working with parameter groups.

  2. Confirm that the parameter change takes effect. To do so, run the following query on the binlog source instance.

    SELECT @@aurora_binlog_replication_max_yield_seconds;

    Your output should be similar to the following.

    +-----------------------------------------------+ | @@aurora_binlog_replication_max_yield_seconds | +-----------------------------------------------+ | 0 | +-----------------------------------------------+

Turning off the large read buffer

You can turn off the entire large read buffer feature as follows.

To turn off the large binary log read buffer for an Aurora MySQL cluster
  1. Reset the aurora_binlog_use_large_read_buffer to OFF or 0.

    Make sure that the DB cluster parameter group associated with the Aurora MySQL cluster has aurora_binlog_use_large_read_buffer set to 0. For more information about setting configuration parameters using parameter groups, see Working with parameter groups.

  2. On the binlog source instance, run the following query.

    SELECT @@ aurora_binlog_use_large_read_buffer;

    Your output should be similar to the following.

    +---------------------------------------+ | @@aurora_binlog_use_large_read_buffer | +---------------------------------------+ | 0 | +---------------------------------------+

Setting up enhanced binlog

Enhanced binlog reduces the compute performance overhead caused by turning on binlog, which can reach up to 50% in certain cases. With enhanced binlog, this overhead can be reduced to about 13%. To reduce overhead, enhanced binlog writes the binary and transactions logs to storage in parallel, which minimizes the data written at the transaction commit time.

Using enhanced binlog also improves database recovery time after restarts and failovers by up to 99% compared to community MySQL binlog. The enhanced binlog is compatible with existing binlog-based workloads, and you interact with it the same way you interact with the community MySQL binlog.

Enhanced binlog is available on Aurora MySQL version 3.03.1 and higher.

Configuring enhanced binlog parameters

You can switch between community MySQL binlog and enhanced binlog by turning on/off the enhanced binlog parameters. The existing binlog consumers can continue to read and consume the binlog files without any gaps in the binlog file sequence.

To turn on enhanced binlog
Parameter Default Description
binlog_format Set the binlog_format parameter to the binary logging format of your choice to turn on enhanced binlog. Make sure the binlog_format parameter isn't set to OFF. For more information, see Configuring Aurora MySQL binary logging.
aurora_enhanced_binlog 0 Set the value of this parameter to 1 in the DB cluster parameter group associated with the Aurora MySQL cluster. When you change the value of this parameter, you must reboot the writer instance when the DBClusterParameterGroupStatus value is shown as pending-reboot.
binlog_backup 1 Turn off this parameter to turn on enhanced binlog. To do so, set the value of this parameter to 0.
binlog_replication_globaldb 1 Turn off this parameter to turn on enhanced binlog. To do so, set the value of this parameter to 0.
Important

You can turn off the binlog_backup and binlog_replication_globaldb parameters only when you use enhanced binlog.

To turn off the enhanced binlog
Parameter Description
aurora_enhanced_binlog Set the value of this parameter to 0 in the DB cluster parameter group associated with the Aurora MySQL cluster. Whenever you change the value of this parameter, you must reboot the writer instance when the DBClusterParameterGroupStatus value is shown as pending-reboot.
binlog_backup Turn on this parameter when you turn off enhanced binlog. To do so, set the value of this parameter to 1.
binlog_replication_globaldb Turn on this parameter when you turn off enhanced binlog. To do so, set the value of this parameter to 1.

To check whether enhanced binlog is turned on, use the following command in the MySQL client:

mysql>show status like 'aurora_enhanced_binlog'; +------------------------+--------+ | Variable_name | Value | +------------------------+--------+ | aurora_enhanced_binlog | ACTIVE | +------------------------+--------+ 1 row in set (0.00 sec)

When enhanced binlog is turned on, the output shows ACTIVE for aurora_enhanced_binlog.

Other related parameters

When you turn on the enhanced binlog, the following parameters are affected:

  • The max_binlog_size parameter is visible but not modifiable. It's default value 134217728 is automatically adjusted to 268435456 when enhanced binlog is turned on.

  • Unlike in community MySQL binlog, the binlog_checksum doesn't act as a dynamic parameter when the enhanced binlog is turned on. For the change to this parameter to take effect, you must manually reboot the DB cluster even when the ApplyMethod is immediate.

  • The value you set on the binlog_order_commits parameter has no effect on the order of the commits when enhanced binlog is turned on. The commits are always ordered without any further performance implications.

Differences between enhanced binlog and community MySQL binlog

Enhanced binlog interacts differently with clones, backups, and Aurora global database when compared to community MySQL binlog. We recommend that you understand the following differences before using enhanced binlog.

  • Enhanced binlog files from the source DB cluster aren't available on a cloned DB cluster.

  • Enhanced binlog files aren't included in Aurora backups. Therefore, enhanced binlog files from the source DB cluster aren't available after restoring a DB cluster despite any retention period set on it.

  • When used with an Aurora global database, the enhanced binlog files of the primary DB cluster aren't replicated to the DB cluster in the secondary regions.

Examples

The following examples illustrate the differences between enhanced binlog and community MySQL binlog.

On a restored or cloned DB cluster

When enhanced binlog is turned on, the historical binlog files aren't available in the restored or cloned DB cluster. After a restore or clone operation, if binlog is turned on, the new DB cluster starts writing its own sequence of binlog files, starting from 1 (mysql-bin-changelog.000001).

To turn on enhanced binlog after a restore or clone operation, set the required DB cluster parameters on the restored or cloned DB cluster. For more information, see Configuring enhanced binlog parameters.

Example Clone or restore operation performed when enhanced binlog is turned on

Source DB Cluster:

mysql> show binary logs; +----------------------------+-----------+-----------+ | Log_name | File_size | Encrypted | +----------------------------+-----------+-----------+ | mysql-bin-changelog.000001 | 156 | No | | mysql-bin-changelog.000002 | 156 | No | | mysql-bin-changelog.000003 | 156 | No | | mysql-bin-changelog.000004 | 156 | No | --> Enhanced Binlog turned on | mysql-bin-changelog.000005 | 156 | No | --> Enhanced Binlog turned on | mysql-bin-changelog.000006 | 156 | No | --> Enhanced Binlog turned on +----------------------------+-----------+-----------+ 6 rows in set (0.00 sec)

On a restored or cloned DB cluster, binlog files aren't backed up when enhanced binlog is turned on. To avoid discontinuity in the binlog data, the binlog files written before turning on the enhanced binlog are also not available.

mysql>show binary logs; +----------------------------+-----------+-----------+ | Log_name | File_size | Encrypted | +----------------------------+-----------+-----------+ | mysql-bin-changelog.000001 | 156 | No | --> New sequence of Binlog files +----------------------------+-----------+-----------+ 1 row in set (0.00 sec)
Example Clone or restore operation performed when enhanced binlog is turned off

Source DB cluster:

mysql>show binary logs; +----------------------------+-----------+-----------+ | Log_name | File_size | Encrypted | +----------------------------+-----------+-----------+ | mysql-bin-changelog.000001 | 156 | No | | mysql-bin-changelog.000002 | 156 | No | --> Enhanced Binlog enabled | mysql-bin-changelog.000003 | 156 | No | --> Enhanced Binlog enabled | mysql-bin-changelog.000004 | 156 | No | | mysql-bin-changelog.000005 | 156 | No | | mysql-bin-changelog.000006 | 156 | No | +----------------------------+-----------+-----------+ 6 rows in set (0.00 sec)

On a restored or cloned DB cluster, binlog files written after turning off the enhanced binlog are available.

mysql>show binary logs; +----------------------------+-----------+-----------+ | Log_name | File_size | Encrypted | +----------------------------+-----------+-----------+ | mysql-bin-changelog.000004 | 156 | No | | mysql-bin-changelog.000005 | 156 | No | | mysql-bin-changelog.000006 | 156 | No | +----------------------------+-----------+-----------+ 1 row in set (0.00 sec)

On an Amazon Aurora global database

On an Amazon Aurora global database, the binlog data of the primary DB cluster isn't replicated to the secondary DB clusters. After a cross-Region failover process, the binlog data isn't available in the newly promoted primary DB cluster. If binlog is turned on, the newly promoted DB cluster starts its own sequence of binlog files, starting from 1 (mysql-bin-changelog.000001).

To turn on enhanced binlog after failover, you must set the required DB cluster parameters on the secondary DB cluster. For more information, see Configuring enhanced binlog parameters.

Example Global database failover operation is performed when enhanced binlog is turned on

Old primary DB Cluster (before failover):

mysql>show binary logs; +----------------------------+-----------+-----------+ | Log_name | File_size | Encrypted | +----------------------------+-----------+-----------+ | mysql-bin-changelog.000001 | 156 | No | | mysql-bin-changelog.000002 | 156 | No | | mysql-bin-changelog.000003 | 156 | No | | mysql-bin-changelog.000004 | 156 | No | --> Enhanced Binlog enabled | mysql-bin-changelog.000005 | 156 | No | --> Enhanced Binlog enabled | mysql-bin-changelog.000006 | 156 | No | --> Enhanced Binlog enabled +----------------------------+-----------+-----------+ 6 rows in set (0.00 sec)

New primary DB cluster (after failover):

Binlog files aren't replicated to secondary regions when enhanced binlog is turned on. To avoid discontinuity in the binlog data, the binlog files written before turning on the enhanced binlog aren't available.

mysql>show binary logs; +----------------------------+-----------+-----------+ | Log_name | File_size | Encrypted | +----------------------------+-----------+-----------+ | mysql-bin-changelog.000001 | 156 | No | --> Fresh sequence of Binlog files +----------------------------+-----------+-----------+ 1 row in set (0.00 sec)
Example Global database failover operation is performed when enhanced binlog is turned off

Source DB Cluster:

mysql>show binary logs; +----------------------------+-----------+-----------+ | Log_name | File_size | Encrypted | +----------------------------+-----------+-----------+ | mysql-bin-changelog.000001 | 156 | No | | mysql-bin-changelog.000002 | 156 | No | --> Enhanced Binlog enabled | mysql-bin-changelog.000003 | 156 | No | --> Enhanced Binlog enabled | mysql-bin-changelog.000004 | 156 | No | | mysql-bin-changelog.000005 | 156 | No | | mysql-bin-changelog.000006 | 156 | No | +----------------------------+-----------+-----------+ 6 rows in set (0.00 sec)

Restored or cloned DB cluster:

Binlog files that are written after turning off the enhanced binlog are replicated and are available in the newly promoted DB cluster.

mysql>show binary logs; +----------------------------+-----------+-----------+ | Log_name | File_size | Encrypted | +----------------------------+-----------+-----------+ | mysql-bin-changelog.000004 | 156 | No | | mysql-bin-changelog.000005 | 156 | No | | mysql-bin-changelog.000006 | 156 | No | +----------------------------+-----------+-----------+ 3 rows in set (0.00 sec)

Amazon CloudWatch metrics for enhanced binlog

The following Amazon CloudWatch metrics are published only when enhanced binlog is turned on.

CloudWatch metric Description Units
ChangeLogBytesUsed The amount of storage used by the enhanced binlog. Bytes
ChangeLogReadIOPs The number of read I/O operations performed in the enhanced binlog within a 5-minute interval. Count per 5 minutes
ChangeLogWriteIOPs The number of write disk I/O operations performed in the enhanced binlog within a 5-minute interval. Count per 5 minutes

Enhanced binlog limitations

The following limitations apply to Amazon Aurora DB clusters when enhanced binlog is turned on.

  • Enhanced binlog is only supported on Aurora MySQL version3.03.1 and higher.

  • The enhanced binlog files written on the primary DB cluster aren't copied to the cloned or restored DB clusters.

  • When used with Amazon Aurora global database, the enhanced binlog files of the primary DB cluster aren't replicated to the secondary DB clusters. Therefore, after the failover process, the historical binlog data isn't available in the new primary DB cluster.

  • The following binlog configuration parameters are ignored:

    • binlog_group_commit_sync_delay

    • binlog_group_commit_sync_no_delay_count

    • binlog_max_flush_queue_time

  • You can't drop or rename a corrupted table in a database. To drop these tables, you can contact AWS Support.

  • The binlog I/O cache is disabled when enhanced binlog is turned on. For more information, see Optimizing binary log replication.

    Note

    Enhanced binlog provides similar read performance improvements as binlog I/O cache and better write performance improvements.

  • The backtrack feature is not supported. Enhanced binlog can't be turned on in a DB cluster under the following conditions:

    • DB cluster with the backtrack feature currently enabled.

    • DB cluster where the backtrack feature was previously enabled, but is now disabled.

    • DB cluster restored from a source DB cluster or a snapshot with the backtrack feature enabled.