Convert Table to InnoDB Storage Engine

This section provides a tutorial example on how to convert a database table from MyISAM to InnoDB engine without taking the MySQL server offline.

If you created a table from an older version of MySQL server, the table is probably still using the MyISAM storage engine. You can convert the table to use the InnoDB storage engine, following what I did below:

1. Confirm that the table "body" is using MyISAM by reading the "information_schema.tables" table or run "show create table ..." statement.

mysql> select * from information_schema.tables where table_name='body';

TABLE_NAME ENGINE TABLE_ROWS AVG_ROW_LENGTH DATA_LENGTH INDEX_LENGTH
---------- ------ ---------- -------------- ----------- ------------
body       MyISAM    2000000          10616 21233518436     25873408

2. Verify the storage file names of the table. MyISAM uses two files: *.MYD for data and *.MYI for the primary key index.

herong$ sudo ls -l  /var/lib/mysql/herong/body*

-rw-r-----. 1 mysql mysql        3535 Nov 13 15:07 body_888.sdi
-rw-r-----. 1 mysql mysql 21233518436 Nov 13 15:22 body.MYD
-rw-r-----. 1 mysql mysql    25873408 Nov 13 15:22 body.MYI

3. Change the storage engine of the table without taking the MySQL server offline.

mysql> ALTER TABLE body ENGINE InnoDB;

Query OK, 2000000 rows affected (58 min 36.64 sec)
Records: 2000000  Duplicates: 0  Warnings: 0

4. Verify the table information and storage files.

mysql> select * from information_schema.tables where table_name='body';

TABLE_NAME ENGINE TABLE_ROWS AVG_ROW_LENGTH DATA_LENGTH INDEX_LENGTH
---------- ------ ---------- -------------- ----------- ------------
body       InnoDB    2000000          10616 21233518436    25873408

herong$ sudo ls -l  /var/lib/mysql/herong/body*
-rw-r-----. 1 mysql mysql 32119980032 Nov 13 15:08 body.ibd

The output confirms that:

Or you can create a new table in InnoDB from the old table with the following "CREATE ... AS SELECT ..." statement. Then take the MySQL server offline and rename the new table with the old name.

CREATE TABLE new_table ENGINE=InnoDB AS SELECT * FROM old_table;

Table of Contents

 About This Book

 Introduction of SQL

 MySQL Introduction and Installation

 Introduction of MySQL Programs

 PHP Programs and MySQL Server

 Perl Programs and MySQL Servers

 Java Programs and MySQL Servers

 Datatypes and Data Literals

 Operations and Expressions

 Character Strings and Bit Strings

 Commonly Used Functions

 Table Column Types for Different Types of Values

 Using DDL to Create Tables and Indexes

 Using DML to Insert, Update and Delete Records

 Using SELECT to Query Database

 Window Functions for Statistical Analysis

 Use Index for Better Performance

 Transaction Management and Isolation Levels

 Locks Used in MySQL

 Defining and Calling Stored Procedures

 Variables, Loops and Cursors Used in Stored Procedures

 System, User-Defined and Stored Procedure Variables

 MySQL Server Administration

Storage Engines in MySQL Server

 What Are Storage Engines

 What Is InnoDB Storage Engine

Convert Table to InnoDB Storage Engine

 Clustered Index Used by InnoDB Engine

 Statistic Information on InnoDB Tables

 MySQL Status Variables for InnoDB Engine

 MySQL System Variables for InnoDB Engine

 InnoDB Storage Engine - Primary and Secondary Indexes

 Performance Tuning and Optimization

 Bulk Changes on Large Tables

 MySQL Server on macOS

 Installing MySQL Server on Linux

 Connection, Performance and Second Instance on Linux

 Archived Tutorials

 References

 Full Version in PDF/EPUB