Connecting orphaned .ibd files

There are two ways InnoDB can organize tablespaces. First is when all data, indexes and system buffers are stored in a single tablespace. This is typicaly one or several ibdata files. A well known innodb_file_per_table option brings the second one. Tables and system areas are split into different files. Usually system tablespace is located in ibdata1 file and every InnoDB table has two files e.g.  actor.frm and actor.ibd.

The annoying thing about .ibd files you can’t easily copy the an .ibd file to another MySQL server. If you try to very often you’ll get an error in the log:

InnoDB: Error: tablespace id is 10 in the data dictionary
InnoDB: but in file ./sakila/actor.ibd it is 15!

However sometimes you have to connect the .ibd file to an alien ibdata1.

There are several situation when you have to:

1. ibdata1 is erroneously removed

2. ibdata1 is heavily corrupted and innodb_force_recovery doesn’t help

Chris Calender suggests two methods. The first is create/drop the table many times until space_id in InnoDB dictionary and .ibd file match. The second is to edit space_id inside .ibd file with a hex editor.

I would like to elaborate the second method.

But let’s understand first what’s going on and why InnoDB refuses to use suggested .ibd file.

There is an InnoDB dictionary. It consists of several internal tables. For our topic only SYS_TABLES and SYS_INDEXES are relevant. These are usual InnoDB tables, but they’re hidden from a user(you can see them in information_scheme database in Percona Server though).

The structure of these tables is following:

SYS_TABLES:

CREATE TABLE `SYS_TABLES` (
`NAME` varchar(255) NOT NULL default '',
`ID` bigint(20) unsigned NOT NULL default '0',
`N_COLS` int(10) default NULL,
`TYPE` int(10) unsigned default NULL,
`MIX_ID` bigint(20) unsigned default NULL,
`MIX_LEN` int(10) unsigned default NULL,
`CLUSTER_NAME` varchar(255) default NULL,
`SPACE` int(10) unsigned default NULL,
PRIMARY KEY  (`NAME`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1

SYS_INDEXES:

CREATE TABLE `SYS_INDEXES` (
`TABLE_ID` bigint(20) unsigned NOT NULL default '0',
`ID` bigint(20) unsigned NOT NULL default '0',
`NAME` varchar(120) default NULL,
`N_FIELDS` int(10) unsigned default NULL,
`TYPE` int(10) unsigned default NULL,
`SPACE` int(10) unsigned default NULL,
`PAGE_NO` int(10) unsigned default NULL,
PRIMARY KEY  (`TABLE_ID`,`ID`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1

Please note field SPACE. For table actor it is equal to 15:

mysql> select * from `INNODB_SYS_TABLES` where `SCHEMA` = 'sakila' AND `NAME` = 'actor'\G
*************************** 1. row ***************************
SCHEMA: sakila
NAME: actor
ID: 13
N_COLS: 2147483652
TYPE: 1
MIX_ID: 0
MIX_LEN: 0
CLUSTER_NAME:
SPACE: 15
1 row in set (0.00 sec)

SPACE is equal to 15 in all actor’s indexes:

mysql> select * from INNODB_SYS_INDEXES WHERE TABLE_ID = 13\G
*************************** 1. row ***************************
TABLE_ID: 13
ID: 15
NAME: PRIMARY
N_FIELDS: 1
TYPE: 3
SPACE: 15
PAGE_NO: 3
*************************** 2. row ***************************
TABLE_ID: 13
ID: 16
NAME: idx_actor_last_name
N_FIELDS: 1
TYPE: 0
SPACE: 15
PAGE_NO: 4
2 rows in set (0.00 sec)

In InnoDB world actor.ibd is a tablespace. It has space_id and it is equal to 15 for this particular table at this particular server.

As you can see secondary indexes are stored in actor.ibd as well.

But where is space_id in actor.ibd?

Like any other tablespace actor.ibd costsists of a set of InnoDB pages. A page is 16k long (UNIV_PAGE_SIZE in the source code).

Let’s take a look at the page header:

Name Size Description
FIL_PAGE_SPACE_OR_CHKSUM 4 /* in < MySQL-4.0.14 space id the
page belongs to (== 0) but in later
versions the ‘new’ checksum of the
page */
FIL_PAGE_OFFSET 4 ordinal page number from start of space
FIL_PAGE_PREV 4 offset of previous page in key order
FIL_PAGE_NEXT 4 offset of next page in key order
FIL_PAGE_LSN 8 log serial number of page’s latest log record
FIL_PAGE_TYPE 2 current defined types are: FIL_PAGE_INDEX, FIL_PAGE_UNDO_LOG, FIL_PAGE_INODE, FIL_PAGE_IBUF_FREE_LIST
FIL_PAGE_FILE_FLUSH_LSN 8 “the file has been flushed to disk at least up to this lsn” (log serial number), valid only on the first page of the file
FIL_PAGE_ARCH_LOG_NO_OR_SPACE_NO 4 /* starting from 4.1.x this
contains the space id of the page */

So, space_id is 4 bytes written to every InnoDB page. An .ibd file can be huge, while ibdata1 is usually smaller. Thus, it is easier to modify space_id in InnoDB dictionary once than in every InnoDB page.

How let’s connect actor.ibd from sakila database taken from some MySQL server.

0. Create empty InnoDB tablespace.

1. Create the table:

mysql>CREATE TABLE actor (
actor_id SMALLINT UNSIGNED NOT NULL AUTO_INCREMENT,
first_name VARCHAR(45) NOT NULL,
last_name VARCHAR(45) NOT NULL,
last_update TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY  (actor_id),
KEY idx_actor_last_name (last_name)
)ENGINE=InnoDB DEFAULT CHARSET=utf8;

This command will create respective records in SYS_TABLES and SYS_INDEXES.

2. Now let’s modify SPACE in InnoDB dictionary. MySQL must be stopped at this point. There is a tool ibdconnect in Percona InnoDB Recovery Tool. Make sure you’re using the latest version from the trunk.

It reads space_id from an .ibd file and updates the dictionary in ibdata1.

# ./ibdconnect -o /var/lib/mysql/ibdata1 -f /var/lib/mysql/sakila/actor.ibd -d sakila -t actor
actor.ibd
actor.ibd belongs to space #15
... Skipped output...
SYS_TABLES is updated successfully
... Skipped output...
SYS_INDEXES is updated successfully

It is possible that space_id from actor.ibd is already used by some other table.
In this case if ibdata was updated MySQL will fail to start with error:

InnoDB: Reading tablespace information from the .ibd files...
InnoDB: Error: trying to add tablespace 15 of name './sakila/customer.ibd'
InnoDB: to the tablespace memory cache, but tablespace
InnoDB: 15 of name './sakila/actor.ibd' already exists in the tablespace
InnoDB: memory cache!

To refrain from such error ibdconnect does check if the space_id is already used.
It will refuse to update ibdata1:

$ ./ibdconnect -o ibdata1 -f t2.ibd -d sakila -t actor
...
Error: Space id: 12 is already used in InnoDB dictionary for table test/t2

In this case you need to drop table `test`.`t2` and create it again. InnoDB will assign other space_id, thus 12 will be freed.

3. Now SPACE is modified in the dictionary, but checksums are bad. To regenerate them use innochecksum from the same toolset. Run it two times:

# ./innochecksum -f /var/lib/mysql/ibdata1
page 8 invalid (fails new style checksum)
page 8: new style: calculated = 0x B7C5C82C; recorded = 0x BFE71C21
fixing new checksum of page 8
page 11 invalid (fails new style checksum)
page 11: new style: calculated = 0x E4189B9B; recorded = 0x C168689B
fixing new checksum of page 11
#
# ./innochecksum -f /var/lib/mysql/ibdata1
page 8 invalid (fails old style checksum)
page 8: old style: calculated = 0x 8195646B; recorded = 0x DA79A2EE
fixing old checksum of page 8
page 8 invalid (fails new style checksum)
page 8: new style: calculated = 0x 119FD630; recorded = 0x B7C5C82C
fixing new checksum of page 8
page 11 invalid (fails old style checksum)
page 11: old style: calculated = 0x 908297E7; recorded = 0x 6536CEE8
fixing old checksum of page 11
page 11 invalid (fails new style checksum)
page 11: new style: calculated = 0x D5DC3269; recorded = 0x E4189B9B
fixing new checksum of page 11

4. The third time to be sure ibdata1 has valid checksums:

#./innochecksum /var/lib/mysql/ibdata1
#

5. Now you can start MySQL and take a dump from the table. The table is accessible, but due to obvious reason it shold not be used in production.

The tool ibdconnect was tested on MySQL 5.1 on CentOS 5.6 x86_64. However it expected to work on all versions of MySQL/InnoDB.