Documentation Home
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 32.8Mb
PDF (A4) - 32.8Mb
PDF (RPM) - 30.8Mb
HTML Download (TGZ) - 7.8Mb
HTML Download (Zip) - 7.9Mb
HTML Download (RPM) - 6.7Mb
Man Pages (TGZ) - 143.5Kb
Man Pages (Zip) - 203.6Kb
Info (Gzip) - 3.0Mb
Info (Zip) - 3.0Mb


Pre-General Availability Draft: 2017-07-24

13.4.2.2 CHANGE REPLICATION FILTER Syntax

CHANGE REPLICATION FILTER filter[, filter]
	[, ...] [FOR CHANNEL channel_name]

filter:
    REPLICATE_DO_DB = (db_list)
  | REPLICATE_IGNORE_DB = (db_list)
  | REPLICATE_DO_TABLE = (tbl_list)
  | REPLICATE_IGNORE_TABLE = (tbl_list)
  | REPLICATE_WILD_DO_TABLE = (wild_tbl_list)
  | REPLICATE_WILD_IGNORE_TABLE = (wild_tbl_list)
  | REPLICATE_REWRITE_DB = (db_pair_list)

db_list:
    db_name[, db_name][, ...]

tbl_list:
    db_name.table_name[, db_table_name][, ...]
wild_tbl_list:
    'db_pattern.table_pattern'[, 'db_pattern.table_pattern'][, ...]

db_pair_list:
    (db_pair)[, (db_pair)][, ...]

db_pair:
    from_db, to_db

CHANGE REPLICATION FILTER sets one or more replication filtering rules on the slave in the same way as starting the slave mysqld with replication filtering options such as --replicate-do-db or --replicate-wild-ignore-table. Unlike the case with the server options, this statement does not require restarting the server to take effect, only that the slave SQL thread be stopped using STOP SLAVE SQL_THREAD first (and restarted with START SLAVE SQL_THREAD afterwards). CHANGE REPLICATION FILTER requires the REPLICATION_SLAVE_ADMIN or SUPER privilege. Use the FOR CHANNEL channel_name clause to make a replication filter specific to a replication channel, for example on a multi-source replication slave. Filters applied without a specific FOR CHANNEL clause are considered global filters, meaning that they are applied to all replication channels.

The following list shows the CHANGE REPLICATION FILTER options and how they relate to --replicate-* server options:

  • REPLICATE_DO_DB: Include updates based on database name. Equivalent to --replicate-do-db.

  • REPLICATE_IGNORE_DB: Exclude updates based on database name. Equivalent to --replicate-ignore-db.

  • REPLICATE_DO_TABLE: Include updates based on table name. Equivalent to --replicate-do-table.

  • REPLICATE_IGNORE_TABLE: Exclude updates based on table name. Equivalent to --replicate-ignore-table.

  • REPLICATE_WILD_DO_TABLE: Include updates based on wildcard pattern matching table name. Equivalent to --replicate-wild-do-table.

  • REPLICATE_WILD_IGNORE_TABLE: Exclude updates based on wildcard pattern matching table name. Equivalent to --replicate-wild-ignore-table.

  • REPLICATE_REWRITE_DB: Perform updates on slave after substituting new name on slave for specified database on master. Equivalent to --replicate-rewrite-db.

The precise effects of REPLICATE_DO_DB and REPLICATE_IGNORE_DB filters are dependent on whether statement-based or row-based replication is in effect. See Section 18.2.5, “How Servers Evaluate Replication Filtering Rules”, for more information.

Multiple replication filtering rules can be created in a single CHANGE REPLICATION FILTER statement by separating the rules with commas, as shown here:

CHANGE REPLICATION FILTER
    REPLICATE_DO_DB = (d1), REPLICATE_IGNORE_DB = (d2);

Issuing the statement just shown is equivalent to starting the slave mysqld with the options --replicate-do-db=d1 --replicate-ignore-db=d2.

On a multi-source replication slave, which uses multiple replication channels to process transaction from different sources, use the FOR CHANNEL channel_name clause to set a replication filter on a replication channel:

CHANGE REPLICATION FILTER REPLICATE_DO_DB = (d1) FOR CHANNEL channel_1;

This enables you to create a channel specific replication filter to filter out selected data from a source. When a FOR CHANNEL clause is provided, the replication filter statement acts on that slave replication channel removing any existing replication filter which has the same filter type as the specified replication filters, and replacing them with the specified filter. Filter types not explicitly listed in the statement are not modified. If issued against a slave replication channel which is not configured, the statement fails with an ER_SLAVE_CONFIGURATION error. If issued against Group Replication channels, the statement fails with an ER_SLAVE_CHANNEL_OPERATION_NOT_ALLOWED error.

On a replication slave with multiple replication channels configured, issuing CHANGE REPLICATION FILTER with noFOR CHANNEL clause configures the replication filter for every configured slave replication channel, and for the global replication filters. For every filter type, if the filter type is listed in the statement, then any existing filter rules of that type are replaced by the filter rules specified in the most recently issued statement, otherwise the old value of the filter type is retained. For more information see Section 18.2.5.4, “Replication Channel Based Filters”.

If the same filtering rule is specified multiple times, only the last such rule is actually used. For example, the two statements shown here have exactly the same effect, because the first REPLICATE_DO_DB rule in the first statement is ignored:

CHANGE REPLICATION FILTER
    REPLICATE_DO_DB = (db1, db2), REPLICATE_DO_DB = (db3, db4);

CHANGE REPLICATION FILTER
    REPLICATE_DO_DB = (db3,db4);
Caution

This behavior differs from that of the --replicate-* filter options where specifying the same option multiple times causes the creation of multiple filter rules.

Names of tables and database not containing any special characters need not be quoted. Values used with REPLICATION_WILD_TABLE and REPLICATION_WILD_IGNORE_TABLE are string expressions, possibly containing (special) wildcard characters, and so must be quoted. This is shown in the following example statements:

CHANGE REPLICATION FILTER
    REPLICATE_WILD_DO_TABLE = ('db1.old%');

CHANGE REPLICATION FILTER
    REPLICATE_WILD_IGNORE_TABLE = ('db1.new%', 'db2.new%');

Values used with REPLICATE_REWRITE_DB represent pairs of database names; each such value must be enclosed in parentheses. The following statement rewrites statements occurring on database db1 on the master to database db2 on the slave:

CHANGE REPLICATION FILTER REPLICATE_REWRITE_DB = ((db1, db2));

The statement just shown contains two sets of parentheses, one enclosing the pair of database names, and the other enclosing the entire list. This is perhap more easily seen in the following example, which creates two rewrite-db rules, one rewriting database dbA to dbB, and one rewriting database dbC to dbD:

CHANGE REPLICATION FILTER
  REPLICATE_REWRITE_DB = ((dbA, dbB), (dbC, dbD));

This statement leaves any existing replication filtering rules unchanged; to unset all filters of a given type, set the filter's value to an explicitly empty list, as shown in this example, which removes all existing REPLICATE_DO_DB and REPLICATE_IGNORE_DB rules:

CHANGE REPLICATION FILTER
    REPLICATE_DO_DB = (), REPLICATE_IGNORE_DB = ();

Setting a filter to empty in this way removes all existing rules, does not create any new ones, and does not restore any rules set at mysqld startup using --replicate-* options on the command line or in the configuration file.

Values employed with REPLICATE_WILD_DO_TABLE and REPLICATE_WILD_IGNORE_TABLE must be in the format db_name.tbl_name.

For more information, see Section 18.2.5, “How Servers Evaluate Replication Filtering Rules”.


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