scp huc_wifi_list#P#p. xx@172.16.32.70:/home/xx
alter table aaa discard tablespace;
alter table aaa import tablespace;
导入时注意文件权限为mysql:mysql
本实验在一台server上启动了2个mysql实例端口分别是3307 3308,目的是将3307的表aaa迁移到3308中去,并打开3308的slave
1.在3308上
mysql> drop table aaa; 干表
Query OK, 0 rows affected (0.01 sec)
mysql> CREATE TABLE `aaa` (
-> `id` int(2) DEFAULT NULL
-> ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 创建和3307上结构一样的空表
Query OK, 0 rows affected (0.00 sec)
在操作系统层面看下数据文件
[root@canal3 leochentest]# ll
total 112
-rw-rw---- 1 mysql mysql 8556 Feb 23 11:50 aaa.frm
-rw-rw---- 1 mysql mysql 98304 Feb 23 11:50 aaa.ibd
-rw-rw---- 1 mysql mysql 61 Feb 8 14:17 db.opt
mysql> alter table aaa discard tablespace; 干掉ibd数据文件
Query OK, 0 rows affected (0.00 sec)
[root@canal3 leochentest]# ll
total 16
-rw-rw---- 1 mysql mysql 8556 Feb 23 11:50 aaa.frm
-rw-rw---- 1 mysql mysql 61 Feb 8 14:17 db.opt
2 在3307上
mysql> use leochentest;
Database changed
mysql>
mysql>
mysql>
mysql> flush tables aaa for export; 锁表,并产生一个tablename.cfg的文件
Query OK, 0 rows affected (0.00 sec)
- 在3307上将数据aaa.cfg和aaa.ibd文件拷贝到3308的对应目录下
[root@canal3 leochentest]# cp aaa.{cfg,ibd} /data/mysql/3308/data/leochentest
3307上解锁表
mysql> unlock tables;
Query OK, 0 rows affected (0.00 sec)
4.3308上执行导入表空间的文件,并打开slave
mysql> Alter table aaa import tablespace;
Query OK, 0 rows affected (0.01 sec)
mysql> select * from aaa;
+------+
| id |
+------+
| 1 |
+------+
1 row in set (0.00 sec)
mysql> start slave ;
Query OK, 0 rows affected (0.01 sec)
mysql> show slave status\G;
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 10.40.20.44
Master_User: repl
Master_Port: 3307
Connect_Retry: 60
Master_Log_File: canal3-bin.000002
Read_Master_Log_Pos: 19705
Relay_Log_File: canal3-relay-bin.000010
Relay_Log_Pos: 284
Relay_Master_Log_File: canal3-bin.000002
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: 19705
Relay_Log_Space: 622
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: 3307
Master_UUID: bbbe1742-0a4b-11e8-b0c0-00000a28142c
Master_Info_File: /data/mysql/3308/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:
Executed_Gtid_Set:
Auto_Position: 0
1 row in set (0.00 sec)
ERROR:
No query specified
CREATE TABLE `test2` (
`id` int(11) DEFAULT NULL,
`name` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci ROW_FORMAT=COMPACT;
CREATE TABLE `test2` (
`id` int(11) DEFAULT NULL,
`name` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci ROW_FORMAT=COMPACT;
ALTER TABLE `test2` ROW_FORMAT=COMPACT;
ALTER TABLE `test2` ROW_FORMAT=DYNAMIC;
Comments