Setting up Replication Slave – MySQL

Introduction:

Replication is one of the basic and most essential feature available in MySQL. Replication allows you to maintain additional copy of database on another server and keep itself updated with latest changes in master databases. Having another copy of data (other than backup) is always a good option. In case of any issues on master server we can always failover to slave and make it a master. This provides high availability. You can have multiple slaves pulling data from a single master, and you can have slaves replicating data off other slaves

There are 2 parts involved in setting up a replication.

Part 1 – Cloning of existing MySQL instance and create a duplicate MySQL environment (similar to master).

This can be done by exporting data using mysqldump and run the sql file created on target database (if data is relatively small) or use “SELECT ... INTO OUTFILE” and “LOAD DATA INFILE”

But relatively easiest way is to setup master slave relationship and set gtid_next variable to the starting gtid of master. This way it will fetch all transactions and make it in sync. Of course you will need GTID to be enabled for this.

Part 2 – Enabling Master – Slave relationship to replicate changes happened on master to slave.

If GTID is enabled, you can configure master – slave using GTID.

If GTID is not enabled, you can use bin_log name and position to configure master – slave.

Setting up replication when GTID is enabled:

So in my current configuration, I have a master where GTID is enabled. After enabling GTID I have loaded the required database “deo”.

I have installed another MySQL setup on another server and enabled GTID.

Parameter Changes:

We need to enable following parameters

Master

server-id=1

We need to assign server ID to master and slave. Remember that server ID should be unique for every MySQL instances in replication.

Also, since GTID is enabled, I am assuming following parameters are setup correctly

gtid_mode=ON
enforce_gtid_consistency=true
log_bin
log_slave_updates=true

Even if GTID is not enabled, you need to setup server_id and log_bin parameters for setting up replication.

Bounce the instance after setting up server_id parameters (and many be GTID parameters if they were not set before).

Slave

server_id=2

Again, I am assuming GTID is enabled on slave mysql instance and above parameters are set correctly.

Bounce the instance after setting up server_id parameters (and many be GTID parameters if they were not set before).

Setting up replication

At this point master looks like following


mysql> show global variables like '%gtid%';
+--------------------------+-------------------------------------------+
| Variable_name | Value |
+--------------------------+-------------------------------------------+
| enforce_gtid_consistency | ON |
| gtid_executed | 2441a23c-b4ae-11e3-9d0b-80c16e2272cc:1-21 |
| gtid_mode | ON |
| gtid_owned | |
| gtid_purged | |
+--------------------------+-------------------------------------------+

mysql> show databases;
+--------------------+
| Database |
+--------------------+
| information_schema |
| deo |
| mysql |
| performance_schema |
| test |
+--------------------+
5 rows in set (0.00 sec)

mysql> show variables like '%server_id%';
+----------------+-------+
| Variable_name | Value |
+----------------+-------+
| server_id | 1 |
| server_id_bits | 32 |
+----------------+-------+

It has one extra database “deo” with few tables in that database.

I will create a replication user on master and grant replication privileges to that user

mysql> CREATE USER 'replicate'@'%' IDENTIFIED BY 'welcome';
Query OK, 0 rows affected (0.04 sec)

mysql> GRANT REPLICATION SLAVE ON *.* TO 'replicate'@'%';
Query OK, 0 rows affected (0.01 sec)

mysql> show master status\G
*************************** 1. row ***************************
File: bin_log.000002
Position: 6740
Binlog_Do_DB:
Binlog_Ignore_DB:
Executed_Gtid_Set: 2441a23c-b4ae-11e3-9d0b-80c16e2272cc:1-23
1 row in set (0.00 sec)

At this point my slave looks like following


mysql> show variables like '%gtid%';
+--------------------------+-----------+
| Variable_name | Value |
+--------------------------+-----------+
| enforce_gtid_consistency | ON |
| gtid_executed | |
| gtid_mode | ON |
| gtid_next | AUTOMATIC |
| gtid_owned | |
| gtid_purged | |
+--------------------------+-----------+

mysql> show variables like '%server_id%';
+----------------+-------+
| Variable_name | Value |
+----------------+-------+
| server_id | 2 |
| server_id_bits | 32 |
+----------------+-------+

mysql> show slave status\G
Empty set (0.00 sec)

At this point we should point the slave to master and start the slave.

Since we are using GTID, we do not have to provide MASTER_LOG_FILE and MASTER_LOG_POS parameters in CHANGE MASTER TO command.

We can simply use MASTER_AUTO_POSITION=1 and MySQL will automatically find the changes it has to replicate.

Pointing slave to master

Use following command to point slave to master

CHANGE MASTER TO MASTER_HOST = 'master_host', MASTER_PORT = master_port, MASTER_USER = 'replicate', MASTER_PASSWORD = 'welcome', MASTER_AUTO_POSITION = 1;
MASTER_HOST is the host name on which master is running
MASTER_PORT is the MySQL port of master
MASTER_USER is the replication user we created in above step. "replicate" in our case
MASTER_PASSWORD is the password we provided for replicate user.
MASTER_AUTO_POSITION = 1. If GTID is enabled, setting this parameter will automatically replicate the changes.

Start Slave

Once we point slave to master, we need to start the slave.

mysql> start slave;
Query OK, 0 rows affected (0.00 sec)

Once you start the slave you can check the status


mysql> show slave status\G
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: advait-1.desktop
Master_User: replicate
Master_Port: 3306
Connect_Retry: 60
Master_Log_File: bin_log.000003
Read_Master_Log_Pos: 191
Relay_Log_File: advait-2-relay-bin.000003
Relay_Log_Pos: 397
Relay_Master_Log_File: bin_log.000003
Slave_IO_Running: Yes
Slave_SQL_Running: Yes
Replicate_Do_DB:
Replicate_Ignore_DB:
Replicate_Do_Table:
Replicate_Ignore_Table:
Replicate_Wild_Do_Table:
Replicate_Wild_Ignore_Table:
Last_Errno: 0
Last_Error:
Skip_Counter: 0
Exec_Master_Log_Pos: 191
Relay_Log_Space: 7243
Until_Condition: None
Until_Log_File:
Until_Log_Pos: 0
Master_SSL_Allowed: No
Master_SSL_CA_File:
Master_SSL_CA_Path:
Master_SSL_Cert:
Master_SSL_Cipher:
Master_SSL_Key:
Seconds_Behind_Master: 0
Master_SSL_Verify_Server_Cert: No
Last_IO_Errno: 0
Last_IO_Error:
Last_SQL_Errno: 0
Last_SQL_Error:
Replicate_Ignore_Server_Ids:
Master_Server_Id: 1
Master_UUID: 2441a23c-b4ae-11e3-9d0b-80c16e2272cc
Master_Info_File: /usr/local/mysql/data/master.info
SQL_Delay: 0
SQL_Remaining_Delay: NULL
Slave_SQL_Running_State: Slave has read all relay log; waiting for the slave I/O thread to update it
Master_Retry_Count: 86400
Master_Bind:
Last_IO_Error_Timestamp:
Last_SQL_Error_Timestamp:
Master_SSL_Crl:
Master_SSL_Crlpath:
Retrieved_Gtid_Set: 2441a23c-b4ae-11e3-9d0b-80c16e2272cc:1-23
Executed_Gtid_Set: 2441a23c-b4ae-11e3-9d0b-80c16e2272cc:1-23,
8c593930-b4da-11e3-9e2d-b499ba05473c:1-4
Auto_Position: 1
1 row in set (0.00 sec)

So if you consider RETRIEVED_GTID and EXECUTED_GTID variable, you will see it has pulled up all transactions from master and applied on slave.

Retrieved_Gtid_Set: 2441a23c-b4ae-11e3-9d0b-80c16e2272cc:1-23
Executed_Gtid_Set: 2441a23c-b4ae-11e3-9d0b-80c16e2272cc:1-23, 8c593930-b4da-11e3-9e2d-b499ba05473c:1-4

Also, if you check databases on slave, you will see “deo” database is visible and it has all the data same as master.

In EXECUTED_GTID_SET variable, you will see 2 GTIDs separated by comma. This is because if you execute some transactions on slave directly, slave will generate its own GTID, which is 8c593930-b4da-11e3-9e2d-b499ba05473c:1-4 in this case.

In order to prevent any transaction happening on slave, we can make slave read only. This will prevent any user from executing any transactions on slave. But this does allow replicate user to keep replicating transactions happening on master.

Making slave readonly

Add a parameter read_only=ON in /etc/my.cnf on slave side and bounce the slave.


mysql> show variables like '%read_only%';
+------------------+-------+
| Variable_name | Value |
+------------------+-------+
| innodb_read_only | OFF |
| read_only | ON |
| tx_read_only | OFF |
+------------------+-------+

Once slave is readonly, no user can do any transactions on slave, except replicate user and root user.

Hope this helps !!

Leave a comment