[MySQL - NCP & OCI 이기종 플랫폼] part 1. Replication

Naver Cloud 플랫폼과 Oracle Cloud 플랫폼 간에 설치형 db로 이중화 구성을 해보았습니다.

 

테스트 환경
Hostname
Platform
Public IP
DB Version
ncp-master
NCP(naver cloud) 
101.101.218.225
8.0.28
oci-slave
OCI(oracle cloud)
146.56.153.8
8.0.28

 

 

■ Master DB서버 생성(NCP)

 

■ Slave DB 서버 생성(OCI)

 

각각의 Mysql DB 설치 진행
 
■ DB Config
## master 
[root@ncp-master ~]# vi /etc/my.cnf

[mysqld]
datadir=/data
socket=/tmp/mysql.sock

expire_logs_days=7
server_id=1
log_bin=mysql.bin

# Disabling symbolic-links is recommended to prevent assorted security risks
symbolic-links=0
# Settings user and group are ignored when systemd is used.
# If you need to run mysqld under a different user or group,
# customize your systemd unit file for mariadb according to the
# instructions in http://fedoraproject.org/wiki/Systemd

log-error=/log/mariadb.log
pid-file=/log/mariadb.pid
[mysqld_safe]
log-error=/log/mariadb.log
pid-file=/log/mariadb.pid

#
# include all files from the config directory
#
!includedir /etc/my.cnf.d



## slave 
[root@oci-slave ~]# vi /etc/my.cnf

[mysqld]
datadir=/data
socket=/tmp/mysql.sock

server_id=2
relay_log=mysql-relay-bin
relay_log_purge=1

# Disabling symbolic-links is recommended to prevent assorted security risks
symbolic-links=0
# Settings user and group are ignored when systemd is used.
# If you need to run mysqld under a different user or group,
# customize your systemd unit file for mariadb according to the
# instructions in http://fedoraproject.org/wiki/Systemd

log-error=/log/mariadb.log
pid-file=/log/mariadb.pid
[mysqld_safe]
log-error=/log/mariadb.log
pid-file=/log/mariadb.pid

#
# include all files from the config directory
#
!includedir /etc/my.cnf.d

 

■ 파라미터 활성화 확인

## master
mysql> show variables like 'log_bin';
+---------------+-------+
| Variable_name | Value |
+---------------+-------+
| log_bin       | ON    |
+---------------+-------+
1 row in set (0.00 sec)


## slave
mysql> show variables like 'relay_log';
+---------------+-----------------+
| Variable_name | Value           |
+---------------+-----------------+
| relay_log     | mysql-relay-bin |
+---------------+-----------------+
1 row in set (0.00 sec)

 

■ replication 유저 생성 및 권한 부여

mysql> create user 'repl'@'%' identified with mysql_native_password by 'repl';
Query OK, 0 rows affected (0.01 sec)

mysql> grant  replication slave,replication client on *.* to 'repl'@'%';
Query OK, 0 rows affected (0.00 sec)

 

■ Master pos확인

mysql> show master status;
+--------------+----------+--------------+------------------+-------------------+
| File         | Position | Binlog_Do_DB | Binlog_Ignore_DB | Executed_Gtid_Set |
+--------------+----------+--------------+------------------+-------------------+
| mysql.000001 |      709 |              |                  |                   |
+--------------+----------+--------------+------------------+-------------------+
1 row in set (0.00 sec)

 

■ Slave 설정 & replication 확인

mysql> CHANGE MASTER TO MASTER_HOST='101.101.218.225', MASTER_USER='repl',MASTER_PASSWORD='repl',MASTER_PORT=3306,MASTER_LOG_FILE='mysql.000001', MASTER_LOG_POS=709,MASTER_CONNECT_RETRY=10;
Query OK, 0 rows affected, 10 warnings (0.02 sec)


mysql> start slave;
Query OK, 0 rows affected, 1 warning (0.01 sec)


mysql> show slave status\G;
*************************** 1. row ***************************
               Slave_IO_State: Waiting for source to send event
                  Master_Host: 101.101.218.225
                  Master_User: repl
                  Master_Port: 3306
                Connect_Retry: 10
              Master_Log_File: mysql.000001
          Read_Master_Log_Pos: 1592
               Relay_Log_File: mysql-relay-bin.000004
                Relay_Log_Pos: 322
        Relay_Master_Log_File: mysql.000001
             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: 1592
              Relay_Log_Space: 879
              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: 811b40f6-03c8-11ed-9d46-f220cd6b3740
             Master_Info_File: mysql.slave_master_info
                    SQL_Delay: 0
          SQL_Remaining_Delay: NULL
      Slave_SQL_Running_State: Replica has read all relay log; waiting for more updates
           Master_Retry_Count: 86400
                  Master_Bind:
      Last_IO_Error_Timestamp:
     Last_SQL_Error_Timestamp:
               Master_SSL_Crl:
           Master_SSL_Crlpath:
           Retrieved_Gtid_Set:
            Executed_Gtid_Set:
                Auto_Position: 0
         Replicate_Rewrite_DB:
                 Channel_Name:
           Master_TLS_Version:
       Master_public_key_path:
        Get_master_public_key: 0
            Network_Namespace:
1 row in set, 1 warning (0.01 sec)

 

동기화 확인

## Master
mysql> create database test;
Query OK, 1 row affected (0.01 sec)


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


## slave
mysql> show databases;
+--------------------+
| Database           |
+--------------------+
| information_schema |
| mysql              |
| performance_schema |
| sys                |
| test               |
+--------------------+
5 rows in set (0.01 sec)

 

타 플랫폼간 replication은 IPsec VPN을 이용해서 하거나 Public IP를 이용해서 진행 가능합니다.
public IP 이용시 아웃바운드 이용 요금이 부과 되기때문에 평소 운영시 사용은 권장하지 않습니다..
DR 구성으로 하기위해 On-prem에 master , Cloud에 slave를 구성할때도 이와 같이 구성하면 될 거 같습니다