MySQL 8.0版本ibd文件恢复

联系:手机/微信(+86 17813235971) QQ(107644445)QQ咨询惜分飞

标题:MySQL 8.0版本ibd文件恢复

作者:惜分飞©版权所有[未经本人同意,不得以任何形式转载,否则有进一步追究法律责任的权利.]

对于单个的ibd文件,大部分情况下可以通过DISCARD TABLESPACE和IMPORT TABLESPACE方式进行恢复

mysql> use test;
Reading table information for completion of table and column names
You can turn off this feature to get a quicker startup with -A

Database changed
mysql> CREATE TABLE `t1` (
    ->   `id` int DEFAULT NULL
    -> ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
Query OK, 0 rows affected (0.01 sec)
mysql> insert into t1 values(1);
Query OK, 1 row affected (0.02 sec)

mysql> insert into t1 values(2);
Query OK, 1 row affected (0.01 sec)

mysql> insert into t1 values(3);
Query OK, 1 row affected (0.00 sec)

关闭mysql服务,备份mysql中的t1.ibd文件

[root@xifenfei ~]# service mysql stop
Shutting down MySQL..... SUCCESS! 
[root@xifenfei test]# cp t1.ibd  t1_bak

启动mysql服务,并删除并创建新的t1表(表结构相同)

[root@xifenfei test]# service mysql start
Starting MySQL..................... SUCCESS! 


[root@xifenfei test]# mysql -uroot -poracle test
mysql: [Warning] Using a password on the command line interface can be insecure.
Reading table information for completion of table and column names
You can turn off this feature to get a quicker startup with -A

Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 8
Server version: 8.0.31 MySQL Community Server - GPL

Copyright (c) 2000, 2022, Oracle and/or its affiliates.

Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql> drop table t1;
Query OK, 0 rows affected (0.20 sec)


mysql> 
mysql> CREATE TABLE `t1` (
    ->   `id` int DEFAULT NULL
    -> ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci;
Query OK, 0 rows affected (0.01 sec)

DISCARD TABLESPACE操作

mysql> ALTER TABLE t1 DISCARD TABLESPACE;
Query OK, 0 rows affected (0.01 sec)

把备份的t1.ibd还原回去并修改权限

[root@xifenfei test]# mv t1_bak t1.ibd
[root@xifenfei test]# ls -ltr
total 112
-rw-r-----. 1 root root 114688 Dec 18 17:24 t1.ibd
[root@xifenfei test]# chown mysql.mysql t1.ibd 

IMPORT TABLESPACE并验证数据

mysql> ALTER TABLE t1 IMPORT TABLESPACE;
Query OK, 0 rows affected, 1 warning (0.24 sec)

mysql> select * from t1;
+------+
| id   |
+------+
|    1 |
|    2 |
|    3 |
+------+
3 rows in set (0.00 sec)

在恢复途中如果遇到表定义不对,或者ibd文件损坏,或者版本不匹配等各种情况,可能在IMPORT TABLESPACE的时候可能出现类似ERROR 1808 (HY000): Schema mismatch (Clustered index validation failed. Because the .cfg file is missing, table definition of the IBD file could be different. Or the data file itself is already corrupted.)错误

mysql>  alter table       `t1` import tablespace;                    
ERROR 1808 (HY000): Schema mismatch (Clustered index validation failed. 
Because the .cfg file is missing, table definition of the IBD file could be different. 
Or the data file itself is already corrupted.)

如果出现此类错误,无法直接通过该方法进行解决,参考frm和ibd文件数据库恢复,使用专业恢复工具进行处理

frm和ibd文件数据库恢复

联系:手机/微信(+86 17813235971) QQ(107644445)QQ咨询惜分飞

标题:frm和ibd文件数据库恢复

作者:惜分飞©版权所有[未经本人同意,不得以任何形式转载,否则有进一步追究法律责任的权利.]

这次客户rm -rf /var/lib/mysql删除文件,删除一半及时终止,但是已经有很多mysql相关文件被删除,重要的ibdata文件已经被删除,并且客户尝试了大量的恢复工作,对该分区进行了大量的写入操作,导致后面通过对xfs文件系统进行分析,确认无法恢复对应的ibdata文件.比较幸运客户需要的核心的mysql库都还在(frm和ibd文件还存在)
20211224105004


对于这种情况,可以参考以前类似的处理方法:[MySQL异常恢复]mysql ibd文件恢复
由于客户无法提供创建表语句需要通过对frm进行解析获取语句,利用mysqlfrm获取表创建语句

E:\3>mysqlfrm --server=root:oracle@192.168.222.79:3306 --diagnostic T_XIFENFEI.frm
WARNING: Using a password on the command line interface can be insecure.
# Source on 192.168.222.79: ... connected.
# CAUTION: The diagnostic mode is a best-effort parse of the .frm file. As such, it may not identify all of 
  the components of the table correctly. This is especially true for damaged files. 
  It will also not read the default values for the columns and the resulting statement may not be syntactically correct.
# Reading .frm file for EVALUATOR_T.frm:
# The .frm file is a TABLE.
# CREATE TABLE Statement:

CREATE TABLE `T_XIFENFEI` (
  `ID` varchar(32) COLLATE `utf8_general_ci` DEFAULT NULL comment '主键',
  `BO_TYPE_DEFINE_ID` varchar(32) COLLATE `utf8_general_ci` DEFAULT NULL comment '业务对象类型ID',
  `MAIN_ID` varchar(32) COLLATE `utf8_general_ci` DEFAULT NULL comment '业务对象主表记录ID',
  `PARENT_ID` varchar(32) COLLATE `utf8_general_ci` DEFAULT NULL comment '父ID',
  `ROW_NUM` decimal(32,0) DEFAULT NULL comment '行号',
  `VERSION` decimal(32,6) DEFAULT NULL comment '版本',
  `CREATE_DATE` datetime DEFAULT NULL comment '创建时间',
  `UPDATE_DATE` datetime DEFAULT NULL comment '更新时间',
  `BO_SOURCE_ROW_ID` varchar(32) COLLATE `utf8_general_ci` DEFAULT NULL comment '来源明细行ID',
  `EVALUATORS` text COLLATE `utf8_general_ci` DEFAULT NULL,
  `IMPORTANCE` decimal(32,6) DEFAULT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8, COMMENT '评分人';
#...done.

对于有些获取语句失败,比如类似这样错误

E:\TEMP\10000246_1108\db\ync2_fssc_2000003>mysqlfrm --server=root:oracle@192.168.222.79:3306 --diagnostic T_XFF.frm
Traceback (most recent call last):
  File "G:\ade\build\Python-2.7.6-windows-x86-64bit\lib\site-packages\cx_Freeze\initscripts\Console.py",
    line 27, in <module>
  File "scripts\mysqlfrm.py", line 419, in <module>
  File ".\mysql\utilities\command\read_frm.py", line 396, in read_frm_files_diagnostic
  File ".\mysql\utilities\common\frm_reader.py", line 1538, in show_create_table_statement
  File ".\mysql\utilities\common\frm_reader.py", line 1385, in _build_create_statement
  File ".\mysql\utilities\common\frm_reader.py", line 1273, in _get_key_columns
IndexError: list index out of range

使用专门的工具对其进行解析
20211224105004


然后利用这些创建表语句在库中创建表,并利用以下方法进行操作

mysql> alter table  `t_xifenfei` discard tablespace;        
Query OK, 0 rows affected (0.00 sec)

--上传老的t_xifenfei.ibd文件,并修改所有者和属组

mysql> alter table  `t_xifenfei` import tablespace;                
Query OK, 0 rows affected, 2 warnings (0.01 sec)

mysql> select count(1) from   `t_xifenfei` ;              
+----------+
| count(1) |
+----------+
|       78 |
+----------+
1 row in set (0.00 sec)

使用类似的方法对于数据进行批量处理,然后使用mysqldump进行导出.在这个ibd的discard和import的过程中,有些异常情况这三种错误的处理

mysql> alter table T_LOG_XIFENFEI                   import tablespace;
ERROR 1808 (HY000): Schema mismatch (Table has ROW_TYPE_DYNAMIC row format, .ibd file has ROW_TYPE_COMPACT row format.)
mysql> alter table     `T_LOG_XIFENFEI` import tablespace;
ERROR 1817 (HY000): Index corrupt: Externally stored column(4) has a reference length of 4 in the cluster index PRIMARY
mysql> alter table       `T_LOG_XIFENFEI` import tablespace;
ERROR 1815 (HY000): Internal error: Cannot reset LSNs in table `XFF`.`T_LOG_XIFENFEI` : Data structure corruption

Schema mismatch (Table has ROW_TYPE_DYNAMIC row format, .ibd file has ROW_TYPE_COMPACT row format.) 这种错误是由于row_format设置不正确导致,重新创建表使用正确的row_format然后执行discard和import操作.
Index corrupt: Externally stored column(4) has a reference length of 4 in the cluster index PRIMARY 这种错误是由于表的创建语句和ibd中记录数据不匹配,主要是由于创建表语句不完全正确导致,重新获取正确语句进行恢复
Internal error: Cannot reset LSNs in table `XFF`.`T_LOG_XIFENFEI` : Data structure corruption 这种错误是由于ibd文件本身不一致无法使用该方法恢复,对于这类情况使用我们专业的工具进行处理
20211224142855