Emergency

Disconnecting a replication slave is easier with MySQL 5.5+ (RESET SLAVE vs. RESET SLAVE ALL)


Posted on:

|

By:


PREVIOUS POST
NEXT POST
Share Button

It’s not uncommon to promote a server from slave to master. One of the key things to protect your data integrity is to make sure that the promoted slave is permanently disconnected from its old master. If not, it may get writes from the old master, which can cause all kinds of data corruption. MySQL provides the handy RESET SLAVE command. But as we’ll see, its behavior has changed along with the MySQL versions and it’s easy to shoot yourself in the foot if you use it incorrectly. So how do you safely disconnect a replication slave?

In short

  • For MySQL 5.0 and 5.1, run STOP SLAVE, CHANGE MASTER TO MASTER_HOST='' and then RESET SLAVE.
  • For MySQL 5.5 and 5.6, run STOP SLAVE and then RESET SLAVE ALL.
  • For all versions, ban master-user, master-host and master-password settings in my.cnf, this may cause huge problems (it’s anyway no longer supported from MySQL 5.5).

If you want to know more details, please read on!

MySQL 5.0/5.1

First let’s consider MySQL 5.0 and 5.1. RESET SLAVE will remove the master.info and relay-log.info files as well as all the relay log files. This looks great, but does it ensure the replica is disconnected from its master?
Let’s try:

This is not expected: instead of removing all settings, some of them are reset to default values. This means that if you run START SLAVE (or if it’s done automatically, for instance when restarting the server without the skip-slave-start option), replication may start again. But as the master position has been deleted, replication will restart at the beginning of the first available binary log, which is very likely to corrupt your data by reexecuting some queries.

Here’s a trick to make RESET SLAVE work as expected: use CHANGE MASTER TO MASTER_HOST='':

Much better! If we try to restart replication, it fails. However, I don’t like the error message, specifically the ‘fix in config file’ part. What happens if we specify the master-user, master-password, master-host and master-port in the my.cnf file?

Let’s disconnect the slave:

Connection settings are automatically restored, which makes disconnecting the replica impossible. And again, if you restart replication, it will read events from the first available binary log file on the master, which is probably not what you want. So never set master-xxx variables in my.cnf!

From MySQL 5.5

Starting with MySQL 5.5, the situation has slightly changed. First the master-xxx variables are no longer supported, which is a great improvement. But the RESET SLAVE statement also behaves differently:

As stated in the documentation, the connection parameters are still held in memory. In any case, you will be able to restart replication, but again as no replication coordinate is specified, replication will start at the beginning of the first available binary log file, with all the nasty consequences we can imagine.

Even worse, the CHANGE MASTER TO MASTER_HOST='' trick no longer works:

Fortunately, the documentation also specifies that we can use RESET SLAVE ALL to remove all replication-related configuration:

Very good! The command does work as expected without any additional tricks. As soon as you are aware of the difference between RESET SLAVE and RESET SLAVE ALL, disconnecting a replication slave is much easier with MySQL 5.5+.

Share Button
PREVIOUS POST
NEXT POST


Stephane Combaudon

Stéphane joined Percona in July 2012, after working as a MySQL DBA for leading French companies such as Dailymotion and France Telecom. In real life, he lives in Paris with his wife and their twin daughters. When not in front of a computer or not spending time with his family, he likes playing chess and hiking.



Tags:

, ,

Categories:
Insight for DBAs, MySQL


Comments

  • Thanks, it always was messed up 😉

  • Thanks Stephane, I’ve always wondered why RESET SLAVE worked this way, now I’ll use RESET SLAVE ALL!

  • But “show master status” still has entries pertaining to log position.
    How do you get rid of that?

  • Stephane Combaudon Post author

    Jake, as long as binary logging is enabled, “show master status” will return something.

    But this is not related to a server being a replica or not: only “show slave status” will give you that information.

  • Stephane,

    I have 3 DB servers. The order of replication is as follows:

    DB1 —->replicates to—-> DB2 —->replicates to —->DB3

    DB1 is the production server. I want to promote DB2 as the production/master database (DB1 is going away), but I STILL want DB3 to replicate from DB2.

    If I run RESET SLAVE ALL on DB2, I assume DB3 will still be able to replicate from DB2… Correct?

    Thanks!

  • Stephane Combaudon Post author

    Werd,

    Yes, correct. RESET SLAVE ALL will only make DB2 forget that it has been a slave of DB1

  • This might be completely unrelated. please pardon my ignorance as i am new to mysql world and learning as much as possible.
    my setup is D01(M) –> D02 (S)
    There are 6 databases on D01. There was an issue and replication broke in test env. before it was looked into (5 days)
    Q — is there a clean way to catch up with replication for just 1 databases. please note that we are on Percona 5.6

  • Stephane Combaudon Post author

Leave a Reply

Your email address will not be published. Required fields are marked *