This section explains how to work with replication filters when multiple replication channels exist, for example in a multi-source replication topology. Before MySQL 8.0, all replication filters were global, so filters were applied to all replication channels. From MySQL 8.0, replication filters can be global or channel specific, enabling you to configure multi-source replicas with replication filters on specific replication channels. Channel specific replication filters are particularly useful in a multi-source replication topology when the same database or table is present on multiple sources, and the replica is only required to replicate it from one source.
For instructions to set up replication channels, see Section 19.1.5, “MySQL Multi-Source Replication”, and for more information on how they work, see Section 19.2.2, “Replication Channels”.
Each channel on a multi-source replica must replicate from a different source. You cannot set up multiple replication channels from a single replica to a single source, even if you use replication filters to select different data to replicate on each channel. This is because the server IDs of replicas must be unique in a replication topology. The source distinguishes replicas only by their server IDs, not by the names of the replication channels, so it cannot recognize different replication channels from the same replica.
On a MySQL server instance that is configured for Group
Replication, channel specific replication filters can be used
on replication channels that are not directly involved with
Group Replication, such as where a group member also acts as a
replica to a source that is outside the group. They cannot be
used on the group_replication_applier
or
group_replication_recovery
channels.
Filtering on these channels would make the group unable to
reach agreement on a consistent state.
For a multi-source replica in a diamond topology (where the
replica replicates from two or more sources, which in turn
replicate from a common source), when GTID-based replication
is in use, ensure that any replication filters or other
channel configuration are identical on all channels on the
multi-source replica. With GTID-based replication, filters are
applied only to the transaction data, and GTIDs are not
filtered out. This happens so that a replica’s GTID set
stays consistent with the source’s, meaning GTID
auto-positioning can be used without re-acquiring filtered out
transactions each time. In the case where the downstream
replica is multi-source and receives the same transaction from
multiple sources in a diamond topology, the downstream replica
now has multiple versions of the transaction, and the result
depends on which channel applies the transaction first. The
second channel to attempt it skips the transaction using GTID
auto-skip, because the transaction’s GTID was added to the
gtid_executed
set by the
first channel. With identical filtering on the channels, there
is no problem because all versions of the transaction contain
the same data, so the results are the same. However, with
different filtering on the channels, the database can become
inconsistent and replication can hang.
When multiple replication channels exist, for example in a multi-source replication topology, replication filters are applied as follows:
Any global replication filter specified is added to the global replication filters of the filter type (
do_db
,do_ignore_table
, and so on).Any channel specific replication filter adds the filter to the specified channel’s replication filters for the specified filter type.
Each replication channel copies global replication filters to its channel specific replication filters if no channel specific replication filter of this type is configured.
Each channel uses its channel specific replication filters to filter the replication stream.
The syntax to create channel specific replication filters
extends the existing SQL statements and command options. When
a replication channel is not specified the global replication
filter is configured to ensure backwards compatibility. The
CHANGE REPLICATION FILTER
statement supports the FOR CHANNEL
clause
to configure channel specific filters online. The
--replicate-*
command options to configure
filters can specify a replication channel using the form
--replicate-
.
Suppose channels filter_type
=channel_name
:filter_details
channel_1
and
channel_2
exist before the server starts;
in this case, starting the replica with the command line
options --replicate-do-db=db1
--replicate-do-db=channel_1:db2
--replicate-do-db=db3
--replicate-ignore-db=db4
--replicate-ignore-db=channel_2:db5
--replicate-wild-do-table=channel_1:db6.t1%
would result in:
Global replication filters:
do_db=db1,db3
;ignore_db=db4
Channel specific filters on channel_1:
do_db=db2
;ignore_db=db4
;wild-do-table=db6.t1%
Channel specific filters on channel_2:
do_db=db1,db3
;ignore_db=db5
These same rules could be applied at startup when included in
the replica's my.cnf
file, like
this:
replicate-do-db=db1
replicate-do-db=channel_1:db2
replicate-ignore-db=db4
replicate-ignore-db=channel_2:db5
replicate-wild-do-table=db6.channel_1.t1%
To monitor the replication filters in such a setup use the
replication_applier_global_filters
and replication_applier_filters
tables.
The replication filter related command options can take an
optional channel
followed by a
colon, followed by the filter specification. The first colon
is interpreted as a separator, subsequent colons are
interpreted as literal colons. The following command options
support channel specific replication filters using this
format:
--replicate-do-db=
channel
:database_id
--replicate-ignore-db=
channel
:database_id
--replicate-do-table=
channel
:table_id
--replicate-ignore-table=
channel
:table_id
--replicate-rewrite-db=
channel
:db1-db2
--replicate-wild-do-table=
channel
:table
pattern
--replicate-wild-ignore-table=
channel
:table
pattern
All of the options just listed can be used in the
replica's my.cnf
file, as with most
other MySQL server startup options, by omitting the two
leading dashes. See
Overview of Replication Filters and Channels, for a
brief example, as well as Section 6.2.2.2, “Using Option Files”.
If you use a colon but do not specify a
channel
for the filter option, for
example
--replicate-do-db=:
,
the option configures the replication filter for the default
replication channel. The default replication channel is the
replication channel which always exists once replication has
been started, and differs from multi-source replication
channels which you create manually. When neither the colon nor
a database_id
channel
is specified the option
configures the global replication filters, for example
--replicate-do-db=
configures the global
database_id
--replicate-do-db
filter.
If you configure multiple
rewrite-db=
options with the same from_name
->to_name
from_name
database, all filters are added together (put into the
rewrite_do
list) and the first one takes
effect.
The pattern
used for the
--replicate-wild-*-table
options can include
any characters allowed in identifiers as well as the wildcards
%
and _
. These work the
same way as when used with the
LIKE
operator; for example,
tbl%
matches any table name beginning with
tbl
, and tbl_
matches
any table name matching tbl
plus one
additional character.
In addition to the --replicate-*
options,
replication filters can be configured using the
CHANGE REPLICATION FILTER
statement. This removes the need to restart the server, but
the replication SQL thread must be stopped while making the
change. To make this statement apply the filter to a specific
channel, use the FOR CHANNEL
clause. For
example:
channel
CHANGE REPLICATION FILTER REPLICATE_DO_DB=(db1) FOR CHANNEL channel_1;
When a FOR CHANNEL
clause is provided, the
statement acts on the specified channel's replication
filters. If multiple types of filters
(do_db
, do_ignore_table
,
wild_do_table
, and so on) are specified,
only the specified filter types are replaced by the statement.
In a replication topology with multiple channels, for example
on a multi-source replica, when no FOR
CHANNEL
clause is provided, the statement acts on
the global replication filters and all channels’ replication
filters, using a similar logic as the FOR
CHANNEL
case. For more information see
Section 15.4.2.2, “CHANGE REPLICATION FILTER Statement”.
When channel specific replication filters have been
configured, you can remove the filter by issuing an empty
filter type statement. For example to remove all
REPLICATE_REWRITE_DB
filters from a
replication channel named channel_1
issue:
CHANGE REPLICATION FILTER REPLICATE_REWRITE_DB=() FOR CHANNEL channel_1;
Any REPLICATE_REWRITE_DB
filters previously
configured, using either command options or
CHANGE REPLICATION FILTER
, are
removed.
The RESET
REPLICA ALL
statement removes channel specific
replication filters that were set on channels deleted by the
statement. When the deleted channel or channels are recreated,
any global replication filters specified for the replica are
copied to them, and no channel specific replication filters
are applied.