MySQL 5.7 Reference Manual Including MySQL NDB Cluster 7.5 and NDB Cluster 7.6
      Information about table definitions is stored both in the
      .frm files, and in the InnoDB
      data dictionary. If
      you move .frm files around, or if the server
      crashes in the middle of a data dictionary operation, these
      sources of information can become inconsistent.
    
      If a data dictionary corruption or consistency issue prevents you
      from starting InnoDB, see
      Section 14.22.2, “Forcing InnoDB Recovery” for information about
      manual recovery.
    
        A symptom of an out-of-sync data dictionary is that a
        CREATE TABLE statement fails. If
        this occurs, look in the server's error log. If the log says
        that the table already exists inside the
        InnoDB internal data dictionary, you have an
        orphan table inside the InnoDB tablespace
        files that has no corresponding .frm file.
        The error message looks like this:
      
InnoDB: Error: table test/parent already exists in InnoDB internal InnoDB: data dictionary. Have you deleted the .frm file InnoDB: and not used DROP TABLE? Have you used DROP DATABASE InnoDB: for InnoDB tables in MySQL version <= 3.23.43? InnoDB: See the Restrictions section of the InnoDB manual. InnoDB: You can drop the orphaned table inside InnoDB by InnoDB: creating an InnoDB table with the same name in another InnoDB: database and moving the .frm file to the current database. InnoDB: Then MySQL thinks the table exists, and DROP TABLE will InnoDB: succeed.
        You can drop the orphan table by following the instructions
        given in the error message. If you are still unable to use
        DROP TABLE successfully, the
        problem may be due to name completion in the
        mysql client. To work around this problem,
        start the mysql client with the
        --skip-auto-rehash
        option and try DROP TABLE again.
        (With name completion on, mysql tries to
        construct a list of table names, which fails when a problem such
        as just described exists.)
      
        With innodb_file_per_table
        enabled (the default), the following messages may appear at
        startup if a
        file-per-table
        tablespace file (.ibd file) is missing:
      
[ERROR] InnoDB: Operating system error number 2 in a file operation. [ERROR] InnoDB: The error means the system cannot find the path specified. [ERROR] InnoDB: Cannot open datafile for read-only: './test/t1.ibd' OS error: 71 [Warning] InnoDB: Ignoring tablespace `test/t1` because it could not be opened.
        To address these messages, issue DROP
        TABLE statement to remove data about the missing table
        from the data dictionary.
      
        Another symptom of an out-of-sync data dictionary is that MySQL
        prints an error that it cannot open an
        InnoDB file:
      
ERROR 1016: Can't open file: 'child2.ibd'. (errno: 1)
In the error log you can find a message like this:
InnoDB: Cannot find table test/child2 from the internal data dictionary InnoDB: of InnoDB though the .frm file for the table exists. Maybe you InnoDB: have deleted and recreated InnoDB data files but have forgotten InnoDB: to delete the corresponding .frm files of InnoDB tables?
        This means that there is an orphan .frm
        file without a corresponding table inside
        InnoDB. You can drop the orphan
        .frm file by deleting it manually.
      
        If MySQL exits in the middle of an in-place
        ALTER TABLE operation
        (ALGORITHM=INPLACE), you may be left with an
        orphan intermediate table that takes up space on your system.
        Also, an orphan intermediate table in an otherwise empty
        general
        tablespace prevents you from dropping the general
        tablespace. This section describes how to identify and remove
        orphan intermediate tables.
      
        Intermediate table names begin with an
        #sql-ib prefix (e.g.,
        #sql-ib87-856498050). The accompanying
        .frm file has an
        #sql-* prefix and is named differently
        (e.g., #sql-36ab_2.frm).
      
        To identify orphan intermediate tables on your system, you can
        query the Information Schema
        INNODB_SYS_TABLES table. Look for
        table names that begin with #sql. If the
        original table resides in a
        file-per-table
        tablespace, the tablespace file (the
        #sql-*.ibd file) for the orphan
        intermediate table should be visible in the database directory.
      
SELECT * FROM INFORMATION_SCHEMA.INNODB_SYS_TABLES WHERE NAME LIKE '%#sql%';
To remove an orphan intermediate table, perform the following steps:
            In the database directory, rename the
            #sql-*.frm file to match the base name
            of the orphan intermediate table:
          
$> mv #sql-36ab_2.frm #sql-ib87-856498050.frm
              If there is no .frm file, you can
              recreate it. The .frm file must have
              the same table schema as the orphan intermediate table (it
              must have the same columns and indexes) and must be placed
              in the database directory of the orphan intermediate
              table.
            
            Drop the orphan intermediate table by issuing a
            DROP TABLE statement,
            prefixing the name of the table with
            #mysql50# and enclosing the table name in
            backticks. For example:
          
mysql> DROP TABLE `#mysql50##sql-ib87-856498050`;
            The #mysql50# prefix tells MySQL to
            ignore file name safe encoding introduced
            in MySQL 5.1. Enclosing the table name in backticks is
            required to perform SQL statements on table names with
            special characters such as “#”.
          
          If an unexpected exit occurs during an in-place
          ALTER TABLE operation that was
          moving a table to a different tablespace, the recovery process
          restores the table to its original location but leaves an
          orphan intermediate table in the destination tablespace.
        
          If MySQL exits in the middle of an in-place
          ALTER TABLE operation on a
          partitioned table, you may be left with multiple orphan
          intermediate tables, one per partition. In this case, use the
          following procedure to remove the orphan intermediate tables:
        
In a separate instance of the same MySQL version, create a non-partitioned table with the same schema name and columns as the partitioned table.
              Copy the .frm file of the
              non-partitioned table to the database directory with the
              orphan intermediate tables.
            
              Make a copy of the .frm file for each
              table, and rename the .frm files to
              match names of the orphan intermediate tables (as
              described above).
            
              Perform a DROP TABLE
              operation (as described above) for each table.
            
        If MySQL exits in the middle of a table-copying
        ALTER TABLE operation
        (ALGORITHM=COPY), you may be left with an
        orphan temporary table that takes up space on your system. Also,
        an orphan temporary table in an otherwise empty
        general
        tablespace prevents you from dropping the general
        tablespace. This section describes how to identify and remove
        orphan temporary tables.
      
        Orphan temporary table names begin with an
        #sql- prefix (e.g.,
        #sql-540_3). The accompanying
        .frm file has the same base name as the
        orphan temporary table.
      
          If there is no .frm file, you can
          recreate it. The .frm file must have the
          same table schema as the orphan temporary table (it must have
          the same columns and indexes) and must be placed in the
          database directory of the orphan temporary table.
        
        To identify orphan temporary tables on your system, you can
        query the Information Schema
        INNODB_SYS_TABLES table. Look for
        table names that begin with #sql. If the
        original table resides in a
        file-per-table
        tablespace, the tablespace file (the
        #sql-*.ibd file) for the orphan temporary
        table should be visible in the database directory.
      
SELECT * FROM INFORMATION_SCHEMA.INNODB_SYS_TABLES WHERE NAME LIKE '%#sql%';
        To remove an orphan temporary table, drop the table by issuing a
        DROP TABLE statement, prefixing
        the name of the table with #mysql50# and
        enclosing the table name in backticks. For example:
      
mysql> DROP TABLE `#mysql50##sql-540_3`;
        The #mysql50# prefix tells MySQL to ignore
        file name safe encoding introduced in MySQL
        5.1. Enclosing the table name in backticks is required to
        perform SQL statements on table names with special characters
        such as “#”.
      
          If MySQL exits in the middle of an table-copying
          ALTER TABLE operation on a
          partitioned table, you may be left with multiple orphan
          temporary tables, one per partition. In this case, use the
          following procedure to remove the orphan temporary tables:
        
In a separate instance of the same MySQL version, create a non-partitioned table with the same schema name and columns as the partitioned table.
              Copy the .frm file of the
              non-partitioned table to the database directory with the
              orphan temporary tables.
            
              Make a copy of the .frm file for each
              table, and rename the .frm files to
              match the names of the orphan temporary tables (as
              described above).
            
              Perform a DROP TABLE
              operation (as described above) for each table.
            
        With innodb_file_per_table
        enabled, the following message might occur if the
        .frm or .ibd files (or
        both) are missing:
      
InnoDB: in InnoDB data dictionary has tablespace id N,
InnoDB: but tablespace with that id or name does not exist. Have
InnoDB: you deleted or moved .ibd files?
InnoDB: This may also be a table created with CREATE TEMPORARY TABLE
InnoDB: whose .ibd and .frm files MySQL automatically removed, but the
InnoDB: table still exists in the InnoDB internal data dictionary.
If this occurs, try the following procedure to resolve the problem:
            Create a matching .frm file in some
            other database directory and copy it to the database
            directory where the orphan table is located.
          
            Issue DROP TABLE for the
            original table. That should successfully drop the table and
            InnoDB should print a warning to the
            error log that the .ibd file was
            missing.
          
        This procedure describes how to restore orphan
        file-per-table
        .ibd files to another MySQL instance. You
        might use this procedure if the system tablespace is lost or
        unrecoverable and you want to restore .ibd
        file backups on a new MySQL instance.
      
        The procedure is not supported for
        general
        tablespace .ibd files.
      
        The procedure assumes that you only have
        .ibd file backups, you are recovering to
        the same version of MySQL that initially created the orphan
        .ibd files, and that
        .ibd file backups are clean. See
        Section 14.6.1.4, “Moving or Copying InnoDB Tables” for information about
        creating clean backups.
      
Table import limitations outlined in Section 14.6.1.3, “Importing InnoDB Tables” are applicable to this procedure.
On the new MySQL instance, recreate the table in a database of the same name.
mysql>CREATE DATABASE sakila;mysql>USE sakila;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;
Discard the tablespace of the newly created table.
mysql> ALTER TABLE sakila.actor DISCARD TABLESPACE;
            Copy the orphan .ibd file from your
            backup directory to the new database directory.
          
$> cp /backup_directory/actor.ibd path/to/mysql-5.7/data/sakila/
            Ensure that the .ibd file has the
            necessary file permissions.
          
            Import the orphan .ibd file. A warning is
            issued indicating that InnoDB tries to
            import the file without schema verification.
          
mysql> ALTER TABLE sakila.actor IMPORT TABLESPACE; SHOW WARNINGS;
Query OK, 0 rows affected, 1 warning (0.15 sec)
Warning | 1810 | InnoDB: IO Read error: (2, No such file or directory)
Error opening './sakila/actor.cfg', will attempt to import
without schema verification
            Query the table to verify that the .ibd
            file was successfully restored.
          
mysql> SELECT COUNT(*) FROM sakila.actor;
+----------+
| count(*) |
+----------+
|      200 |
+----------+