ibdata1文件损坏时恢复InnoDB单表测试

时间:2021-01-14 13:27:44
 
Preface
 
    ibdata1 file is a shared system tablespace of innodb engine.Although we always set variable of "innodb_file_per_table" to "on" which means put the data of table into their individual ibd files.The ibdata file will still store undo log of our innodb tables.As the ibdata1 file is inevitable to make the MySQL database running properly.Today,I'm gonna demonstrate a way to rescue the table in an instance whose ibdata file is destroied by a certain way such as write several unmeaningful characters into it.
 
Porcedure
 
Backup the instance using Xtrabackup first.
 [root@zlm1 :: ~]
#innobackupex --defaults-file=/data/mysql/mysql3306/my3306.cnf --user=root --password=Passw0rd /data/backup
:: innobackupex: Starting the backup operation
... //Omitted. [root@zlm1 :: /data/backup]
#ls -l
total
drwxr-x--- root root Aug : --05_13-- [root@zlm1 :: /data/backup]

Check the target table which we want to rescue in plan.

 zlm@192.168.56.100: [sysbench]>show tables;
+--------------------+
| Tables_in_sysbench |
+--------------------+
| sbtest1 |
| sbtest2 |
| sbtest3 |
| sbtest4 |
+--------------------+
rows in set (0.00 sec) zlm@192.168.56.100: [sysbench]>select count(*) from sbtest4;
+----------+
| count(*) |
+----------+
| |
+----------+
row in set (0.05 sec) zlm@192.168.56.100: [sysbench]>delete from sbtest4 limit ;
Query OK, rows affected (0.17 sec) zlm@192.168.56.100: [sysbench]>select count(*) from sbtest4;
+----------+
| count(*) |
+----------+
| |
+----------+
row in set (0.00 sec)

Destroy the ibdata1 file with "dd" command.

 [root@zlm1 :: ~]
#cd /data/mysql/mysql3306/data [root@zlm1 :: /data/mysql/mysql3306/data]
#ls -l
total
-rw-r----- mysql mysql Mar : auto.cnf
-rw-r----- mysql mysql Aug : error.log
-rw-r----- mysql mysql Jul : ib_buffer_pool
-rw-r----- mysql mysql Aug : ibdata1
-rw-r----- mysql mysql Aug : ib_logfile0
-rw-r----- mysql mysql Aug : ib_logfile1
-rw-r----- mysql mysql Jul : ib_logfile2
-rw-r----- mysql mysql Aug : ibtmp1
-rw-r----- mysql mysql Aug : innodb_status.
-rw-r----- mysql mysql Jul : innodb_status.
-rw-r----- mysql mysql Jun : innodb_status.
drwxr-x--- mysql mysql Jul : mrbs
drwxr-x--- mysql mysql Mar : mysql
-rw-r----- mysql mysql Aug : mysql.pid
drwxr-x--- mysql mysql Mar : performance_schema
-rw-r----- mysql mysql Jun : relay-bin.
-rw-r----- mysql mysql Jun : relay-bin.index
-rw-r----- mysql mysql Aug : slow.log
drwxr-x--- mysql mysql Mar : sys
drwxr-x--- mysql mysql Jul : sysbench
-rw-r----- mysql mysql Jul : zlm1.log [root@zlm1 :: /data/mysql/mysql3306/data]
#dd if=/dev/zero of=./ibdata1 bs= count=
+ records in
+ records out
bytes ( MB) copied, 1.61997 s, MB/s [root@zlm1 :: /data/mysql/mysql3306/data]
#ls -l|grep ibdata1
-rw-r----- mysql mysql Aug : ibdata1 //The ibdata1 turned out to be 256M and filled with zero.

Restart the MySQL instance.

 zlm@192.168.56.100: [sysbench]>exit
Bye [root@zlm1 :: ~]
#mysqladmin shutdown [root@zlm1 :: ~]
#ps aux|grep mysqld
root 0.0 0.0 pts/ R+ : : grep --color=auto mysqld [root@zlm1 :: ~]
#./mysqld.sh [root@zlm1 :: ~]
#mysql
ERROR (HY000): Can't connect to MySQL server on '192.168.56.100' (111) [root@zlm1 :: ~]
#mysql
ERROR (HY000): Can't connect to MySQL server on '192.168.56.100' (111) [root@zlm1 :: ~]
#cd /data/mysql/mysql3306/data [root@zlm1 :: /data/mysql/mysql3306/data]
#tail error.log
... /Omitted.
--05T12::.242723Z [Note] --secure-file-priv is set to NULL. Operations related to importing and exporting data are disabled
--05T12::.242806Z [Note] mysqld (mysqld 5.7.-log) starting as process ...
--05T12::.249168Z [Note] InnoDB: PUNCH HOLE support available
--05T12::.249207Z [Note] InnoDB: Mutexes and rw_locks use GCC atomic builtins
--05T12::.249213Z [Note] InnoDB: Uses event mutexes
--05T12::.249218Z [Note] InnoDB: GCC builtin __sync_synchronize() is used for memory barrier
--05T12::.249222Z [Note] InnoDB: Compressed tables use zlib 1.2.
--05T12::.249227Z [Note] InnoDB: Using Linux native AIO
--05T12::.249426Z [Note] InnoDB: Number of pools:
--05T12::.249507Z [Note] InnoDB: Using CPU crc32 instructions
--05T12::.251488Z [Note] InnoDB: Initializing buffer pool, total size = 100M, instances = , chunk size = 100M
--05T12::.256630Z [Note] InnoDB: Completed initialization of buffer pool
--05T12::.257913Z [Note] InnoDB: If the mysqld execution user is authorized, page cleaner thread priority can be changed. See the man page of setpriority().
--05T12::.280321Z [Note] InnoDB: Highest supported file format is Barracuda.
:: UTC - mysqld got signal ;
This could be because you hit a bug. It is also possible that this binary
or one of the libraries it was linked against is corrupt, improperly built,
or misconfigured. This error can also be caused by malfunctioning hardware.
Attempting to collect some information that could help diagnose the problem.
As this is a crash and something is definitely wrong, the information
collection process might fail. key_buffer_size=
read_buffer_size=
max_used_connections=
max_threads=
thread_count=
connection_count=
It is possible that mysqld could use up to
key_buffer_size + (read_buffer_size + sort_buffer_size)*max_threads = K bytes of memory
Hope that's ok; if not, decrease some variables in the equation. Thread pointer: 0x0
Attempting backtrace. You can use the following information to find out
where mysqld died. If you see no messages after this, something went
terribly wrong...
stack_bottom = thread_stack 0x30000
mysqld(my_print_stacktrace+0x35)[0xf4a495]
mysqld(handle_fatal_signal+0x4a4)[0x7ce2f4]
/lib64/libpthread.so.(+0xf130)[0x7f6bbee76130]
mysqld(_Z26page_cur_search_with_matchPK11buf_block_tPK12dict_index_tPK8dtuple_t15page_cur_mode_tPmS9_P10page_cur_tP8rtr_info+0x148)[0x1074478]
mysqld(_Z27btr_cur_search_to_nth_levelP12dict_index_tmPK8dtuple_t15page_cur_mode_tmP9btr_cur_tmPKcmP5mtr_t+0x1598)[0x11806d8]
mysqld(_Z30btr_pcur_open_on_user_rec_funcP12dict_index_tPK8dtuple_t15page_cur_mode_tmP10btr_pcur_tPKcmP5mtr_t+0x212)[0x1184b62]
mysqld[0x11df28d]
mysqld(_Z19dict_load_sys_tableP12dict_table_t+0x69)[0x11e0609]
mysqld(_Z9dict_bootv+0xdfb)[0x11bf48b]
mysqld(_Z34innobase_start_or_create_for_mysqlv+0x3212)[0x11150a2]
mysqld[0x100023a]
mysqld(_Z24ha_initialize_handlertonP13st_plugin_int+0x51)[0x819721]
mysqld[0xd39226]
mysqld(_Z40plugin_register_builtin_and_init_core_sePiPPc+0x3e4)[0xd397a4]
mysqld[0x7c48f7]
mysqld(_Z11mysqld_mainiPPc+0x92f)[0x7c7e9f]
/lib64/libc.so.(__libc_start_main+0xf5)[0x7f6bbd857af5]
mysqld[0x7be479]
The manual page at http://dev.mysql.com/doc/mysql/en/crashing.html contains
information that should help you find out what is causing the crash. [root@zlm1 :: /data/mysql/mysql3306/data] //Okay,becasue of the lack of normal ibdata1 file in datadir,the instance cannot be started again.
//Then,how can we resuce the data in target table 'sbtest4'?
//First of all,let's get the ibd and frm file of it from the crashed server.

Copy ibd and frm file of table "sbtest4" to another newly initialized instance on zlm2.

 [root@zlm1 :: /data/mysql/mysql3306/data/sysbench]
#scp sbtest4.* zlm2:/data/backup
sbtest4.frm % .4KB/s :
sbtest4.ibd % 10MB .0MB/s :

Install mysql-utilities package on zlm2.

 [root@zlm2 :: ~]
#mysqlfrm --help
-bash: mysqlfrm: command not found [root@zlm2 :: ~]
#yum install mysql-utilities
Loaded plugins: fastestmirror
base | 3.6 kB ::
epel/x86_64/metalink | 7.0 kB ::
epel | 3.2 kB ::
extras | 3.4 kB ::
updates | 3.4 kB ::
(/): epel/x86_64/group_gz | kB ::
(/): epel/x86_64/updateinfo | kB ::
(/): extras//x86_64/primary_db | kB ::
(/): epel/x86_64/primary | 3.6 MB ::
(/): updates//x86_64/primary_db | 4.3 MB ::
Loading mirror speeds from cached hostfile
* base: mirrors.shu.edu.cn
* epel: mirrors.tongji.edu.cn
* extras: mirrors..com
* updates: mirrors..com
epel /
Resolving Dependencies
--> Running transaction check
---> Package mysql-utilities.noarch :1.3.-.el7 will be installed
--> Processing Dependency: mysql-connector-python for package: mysql-utilities-1.3.-.el7.noarch
--> Running transaction check
---> Package mysql-connector-python.noarch :1.1.-.el7 will be installed
--> Finished Dependency Resolution ... //Omitted. Installed:
mysql-utilities.noarch :1.3.-.el7 Dependency Installed:
mysql-connector-python.noarch :1.1.-.el7 Complete!

Restore the table structure by mysqlfrm.

 [root@zlm2 :: ~]
#cd /data/backup/ [root@zlm2 :: /data/backup]
#ls -l|grep sbtest4
-rw-r----- root root Aug : sbtest4.frm
-rw-r----- root root Aug : sbtest4.ibd [root@zlm2 :: /data/backup]
#mysqlfrm --basedir=/usr/local/mysql --port= --diagnostic ./sbtest4.frm
# WARNING The --port option is not used in the --diagnostic mode.
# WARNING: Cannot generate character set or collation names without the --server option.
# 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 ./sbtest4.frm:
# The .frm file is a TABLE.
# CREATE TABLE Statement: CREATE TABLE `sbtest4` (
`id` int() NOT NULL AUTO_INCREMENT,
`k` int() NOT NULL,
`c` char() NOT NULL,
`pad` char() NOT NULL,
PRIMARY KEY `PRIMARY` (`id`),
KEY `k_4` (`k`)
) ENGINE=InnoDB; #...done.

Create a same table structure in the new instance using the restored "create table" statement.

 [root@zlm2 :: /data/backup]
#mysql
Welcome to the MySQL monitor. Commands end with ; or \g.
Your MySQL connection id is
Server version: 5.7.-log MySQL Community Server (GPL) Copyright (c) , , Oracle and/or its affiliates. All rights reserved. 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. zlm@192.168.56.101: [(none)]>show databases;
+--------------------+
| Database |
+--------------------+
| information_schema |
| mrbs |
| mysql |
| performance_schema |
| sys |
+--------------------+
rows in set (0.00 sec) zlm@192.168.56.101: [(none)]>create database sysbench;
Query OK, row affected (0.00 sec) zlm@192.168.56.101: [(none)]>use sysbench
Database changed
zlm@192.168.56.101: [sysbench]>show tables;
Empty set (0.00 sec) zlm@192.168.56.101: [sysbench]>CREATE TABLE `sbtest4` (
-> `id` int() NOT NULL AUTO_INCREMENT,
-> `k` int() NOT NULL,
-> `c` char() NOT NULL,
-> `pad` char() NOT NULL,
-> PRIMARY KEY `PRIMARY` (`id`),
-> KEY `k_4` (`k`)
-> ) ENGINE=InnoDB;
ERROR (): Column length too big for column 'c' (max = ); use BLOB or TEXT instead
zlm@192.168.56.101: [sysbench]>CREATE TABLE `sbtest4` (
-> `id` int() NOT NULL AUTO_INCREMENT,
-> `k` int() NOT NULL,
-> `c` char() NOT NULL,
-> `pad` char() NOT NULL,
-> PRIMARY KEY `PRIMARY` (`id`),
-> KEY `k_4` (`k`)
-> ) ENGINE=InnoDB;
ERROR (42S02): Table 'sysbench.sbtest4' doesn't exist
zlm@192.168.56.101: [sysbench]>CREATE TABLE `sbtest4_bak` (
-> `id` int() NOT NULL AUTO_INCREMENT,
-> `k` int() NOT NULL,
-> `c` char() NOT NULL,
-> `pad` char() NOT NULL,
-> PRIMARY KEY `PRIMARY` (`id`),
-> KEY `k_4` (`k`)
-> ) ENGINE=InnoDB;
Query OK, rows affected (0.01 sec) zlm@192.168.56.101: [sysbench]>rename table sbtest4_bak to sbtest4;
Query OK, rows affected (0.00 sec) zlm@192.168.56.101: [sysbench]>show tables;
+--------------------+
| Tables_in_sysbench |
+--------------------+
| sbtest4 |
+--------------------+
row in set (0.00 sec) zlm@192.168.56.101: [sysbench]>show create table sbtest4\G
*************************** . row ***************************
Table: sbtest4
Create Table: CREATE TABLE `sbtest4` (
`id` int() NOT NULL AUTO_INCREMENT,
`k` int() NOT NULL,
`c` char() NOT NULL,
`pad` char() NOT NULL,
PRIMARY KEY (`id`),
KEY `k_4` (`k`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8
row in set (0.00 sec) zlm@192.168.56.101: [sysbench]>select count(*) from sbtest4;
+----------+
| count(*) |
+----------+
| |
+----------+
row in set (0.00 sec)

Discard the tablesapce of new table "sbtest4".

 zlm@192.168.56.101: [sysbench]>alter table sbtest4 discard tablespace;
Query OK, rows affected (0.00 sec) [root@zlm2 :: /data/mysql/mysql3306/data/sysbench]
#ls -l
total
-rw-r----- mysql mysql Aug : db.opt
-rw-r----- mysql mysql Aug : sbtest4.frm //After the discard operation,the new ibd file has gone.

Copy the ibd file of table "sbtest4" to the sysbench directory in datadir(notice the owner of file).

 [root@zlm2 :: /data/backup]
#cp sbtest4.ibd /data/mysql/mysql3306/data/sysbench/ [root@zlm2 :: /data/backup]
#ll /data/mysql/mysql3306/data/sysbench/ |grep sbtest4
-rw-r----- mysql mysql Aug : sbtest4.frm
-rw-r----- root root Aug : sbtest4.ibd [root@zlm2 :: /data/backup]
#chown mysql.mysql /data/mysql/mysql3306/data/sysbench/sbtest4.ibd [root@zlm2 :: /data/backup]
#ll /data/mysql/mysql3306/data/sysbench/ |grep sbtest4
-rw-r----- mysql mysql Aug : sbtest4.frm
-rw-r----- mysql mysql Aug : sbtest4.ibd

Import the original tablespace of table "sbtest4".

 zlm@192.168.56.101: [sysbench]>alter table sbtest4 import tablespace;
Query OK, rows affected, warning (1.77 sec) zlm@192.168.56.101: [sysbench]>select count(*) from sbtest4;
+----------+
| count(*) |
+----------+
| |
+----------+
row in set (0.01 sec) //Now the table has been rescued.
//Because of the destroying of ibdata1 in the original instance,it should be restored by Xtrabackup again.
Summary
  • This method is only used to resuce a single table without backup when MySQL instance cannot startup beause of the destoryed ibdata file.
  • mysqlfrm is a tool which can load table structure from .frm files.We need to install the mysql-utilities package first.
  • If we don't have a properly full Xtrabackup and binlog,the .ibd file may lose the undo information on target table.In this situation,it's an incompletely recovery.