이전 part 1에 이어 이기종 플랫폼간 replication을 통해 최대한 무중단 이관이 가능하지 않을까해서 테스트 해보았습니다.
part 1. URL : https://jhdatabase.tistory.com/96
혹시 다른 방법이 있거나 보통은 어떤 방법으로 진행되는지 댓글을 통해 추천 부탁드립니다!!
해당 이관 방법은 지극히 제 개인적인 생각에 의해 진행되었으니..실 작업에서는 충분히 다른 방법을 알아보시고 진행해주시기 바랍니다..!
테스트 환경
Hostname
|
Platform
|
Public IP
|
DB Version
|
ncp-asis
|
NCP(naver cloud)
|
101.101.218.225
|
8.0.28
|
oci-tobe
|
OCI(oracle cloud)
|
146.56.153.8
|
8.0.28
|
■ AS-IS tuning 데이터베이스 이관 계획
mysql> show databases;
+--------------------+
| Database |
+--------------------+
| information_schema |
| mini6sapp |
| mysql |
| performance_schema |
| sys |
| tuning |
+--------------------+
## database 크기
mysql> select table_schema,round(sum(data_length+index_length)/1024/1024,1) from information_schema.tables where table_schema='tuning' group by 1;
+--------------+--------------------------------------------------+
| TABLE_SCHEMA | round(sum(data_length+index_length)/1024/1024,1) |
+--------------+--------------------------------------------------+
| tuning | 279.6 |
+--------------+--------------------------------------------------+
## 테이블 count
mysql> select table_schema,count(*) from information_schema.tables where table_schema='tuning' group by table_schema;
+--------------+----------+
| TABLE_SCHEMA | count(*) |
+--------------+----------+
| tuning | 12 |
+--------------+----------+
## Index 수 확인
mysql> select database_name,count(*) as index_count from mysql.innodb_index_stats where database_name='tuning' group by database_name;
+---------------+-------------+
| database_name | index_count |
+---------------+-------------+
| tuning | 70 |
+---------------+-------------+
## view 수 확인
mysql> select table_schema, count(*) as view_count from information_schema.views where table_schema='tuning' group by table_schema;
+--------------+------------+
| TABLE_SCHEMA | view_count |
+--------------+------------+
| tuning | 2 |
+--------------+------------+
## procedure, function 확인
mysql> select count(ROUTINE_NAME)procedure_count,ROUTINE_TYPE,routine_schema FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_TYPE in ("PROCEDURE","FUNCTION") and routine_schema='tuning' group by ROUTINE_TYPE,routine_schema;
+-----------------+--------------+----------------+
| procedure_count | ROUTINE_TYPE | routine_schema |
+-----------------+--------------+----------------+
| 4 | PROCEDURE | tuning |
+-----------------+--------------+----------------+
## trigger 수 확인
mysql> select TRIGGER_SCHEMA,count(*) TRIGGER_count from INFORMATION_SCHEMA.TRIGGERS where trigger_schema='tunning' group by trigger_schema;
+----------------+---------------+
| TRIGGER_SCHEMA | TRIGGER_count |
+----------------+---------------+
| tuning | 2 |
+----------------+---------------+
■ AS-IS에 1씩 증가하는 테이블을 tuning데이터베이스에 생성
mysql> use tuning
Database changed
mysql> create table jh (count int auto_increment primary key, data varchar(30));
Query OK, 0 rows affected (0.02 sec)
## 소스단에서 data insert
[root@source ~]# while true
> do
> mysql -uroot -proot -h101.101.218.225 -e 'insert into tuning.jh (data) values ("jeonghyun data");'
> sleep 5
> clear
> done
## 실시간 데이터가 들어오늘 것을 가정
mysql> select * from tuning.jh;
+-------+----------------+
| count | data |
+-------+----------------+
| 1 | jeong |
| 2 | jeonghyun data |
| 3 | jeonghyun data |
| 4 | jeonghyun data |
| 5 | jeonghyun data |
| 6 | jeonghyun data |
| 7 | jeonghyun data |
| 8 | jeonghyun data |
| 9 | jeonghyun data |
| 10 | jeonghyun data |
+-------+----------------+
10 rows in set (0.00 sec)
mysql> select * from tuning.jh;
+-------+----------------+
| count | data |
+-------+----------------+
| 1 | jeong |
| 2 | jeonghyun data |
| 3 | jeonghyun data |
| 4 | jeonghyun data |
| 5 | jeonghyun data |
| 6 | jeonghyun data |
| 7 | jeonghyun data |
| 8 | jeonghyun data |
| 9 | jeonghyun data |
| 10 | jeonghyun data |
| 11 | jeonghyun data |
| 12 | jeonghyun data |
+-------+----------------+
12 rows in set (0.01 sec)
■ AS-IS 측 dump 생성
mysqldump유틸리티 이용
[root@ncp-asis ~]# mysqldump --routines --triggers --single-transaction --source-data=1 -uroot -proot tuning > asis.sql
※ scp , ftp 등 이용하여 덤프 파일 tobe측에 전송
■ TO-BE database 생성 & import
mysql> create database tuning;
Query OK, 1 row affected (0.00 sec)
mysql> show databases;
+--------------------+
| Database |
+--------------------+
| information_schema |
| mysql |
| performance_schema |
| sys |
| tuning |
+--------------------+
6 rows in set (0.00 sec)
[root@oci-tobe ~]# chown mysql.mysql asis.sql
## 백업 본 import
[root@oci-tobe ~]# mysql -uroot -proot tuning < asis.sql
■ TO-BE 백업 본 이후 data 따라갈 수 있도록 replication 설정
## 백업 파일에서 POS번호 확인
[root@oci-tobe ~]# vim asis.sql
CHANGE MASTER TO MASTER_LOG_FILE='mysql.000001', MASTER_LOG_POS=67417;
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=67417 ,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: 83587
Relay_Log_File: mysql-relay-bin.000002
Relay_Log_Pos: 16492
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: 83587
Relay_Log_Space: 16702
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)
■ AS-IS 와 TO-BE 데이터 비교
실시간으로 데이터가 insert되면 to-be도 함께 동기화 확인
<AS-IS>
mysql> select * from tuning.jh;
...
| 278 | jeonghyun data |
| 279 | jeonghyun data |
| 280 | jeonghyun data |
| 281 | jeonghyun data |
| 282 | jeonghyun data |
| 283 | jeonghyun data |
| 284 | jeonghyun data |
+-------+----------------+
284 rows in set (0.00 sec)
<TO-BE>
mysql> select * from tuning.jh;
...
| 278 | jeonghyun data |
| 279 | jeonghyun data |
| 280 | jeonghyun data |
| 281 | jeonghyun data |
| 282 | jeonghyun data |
| 283 | jeonghyun data |
| 284 | jeonghyun data |
+-------+----------------+
284 rows in set (0.00 sec)
■ AS-IS down & service ip 수정
아무래도 앞단에 proxy없이 하다보니 수동으로 ip를 내릴 수 밖에 없으며..master 바꿔치기 또한 수동이라 순단이 발생..
## AS-IS down
mysql> shutdown;
## 소스단에서도 끊김
[root@source ~]# while true
> do
> mysql -uroot -proot -h101.101.218.225 -e 'insert into tuning.jh (data) values ("jeonghyun data");'
> sleep 5
> clear
> done
mysql: [Warning] Using a password on the command line interface can be insecure.
ERROR 2002 (HY000): Can't connect to local MySQL server through socket '/tmp/mysql.sock'
■ TO-BE role change
mysql> show slave status\G;
*************************** 1. row ***************************
Slave_IO_State: Reconnecting after a failed source event read
Master_Host: 101.101.218.225
Master_User: repl
Master_Port: 3306
Connect_Retry: 10
Master_Log_File: mysql.000001
Read_Master_Log_Pos: 111223
Relay_Log_File: mysql-relay-bin.000002
Relay_Log_Pos: 44128
Relay_Master_Log_File: mysql.000001
Slave_IO_Running: Connecting
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: 111223
Relay_Log_Space: 44338
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: NULL
Master_SSL_Verify_Server_Cert: No
Last_IO_Errno: 2003
Last_IO_Error: error reconnecting to master 'repl@101.101.218.225:3306' - retry-time: 10 retries: 17 message: Can't connect to MySQL server on '101.101.218.225:3306' (111)
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: 220718 02:23:25
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.00 sec)
mysql> stop slave;
Query OK, 0 rows affected, 1 warning (0.00 sec)
## 소스단 service ip 수정
[root@source ~]# while true
> do
> mysql -uroot -proot -h146.56.153.8 -e 'insert into tuning.jh (data) values ("jeonghyun data");'
> sleep 5
> clear
> done
## 서비스 절체 완료
mysql> select * from tuning.jh;
...생략
| 414 | jeonghyun data |
| 415 | jeonghyun data |
| 416 | jeonghyun data |
| 417 | jeonghyun data |
| 418 | jeonghyun data |
| 419 | jeonghyun data |
| 420 | jeonghyun data |
| 421 | jeonghyun data |
+-------+----------------+
421 rows in set (0.00 sec)
이후 to-be측 db에서 slave 관련 파라미터 제거
'DataBase > MySQL & MariaDB' 카테고리의 다른 글
[MariaDB - Maxscale GUI 구성] (0) | 2022.07.30 |
---|---|
[MariaDB - Galera Cluster & ProxySQL read/write split] (0) | 2022.07.30 |
[MySQL - NCP & OCI 이기종 플랫폼] part 1. Replication (0) | 2022.07.30 |
[MariaDB to MySQL 데이터 이관] use. mysqldump (0) | 2022.07.15 |
[MySQL - InnoDB cluster] part 4 Router설치 (0) | 2022.05.14 |