OPTIMIZE [NO_WRITE_TO_BINLOG | LOCAL]
TABLE tbl_name [, tbl_name] ...
OPTIMIZE TABLE reorganizes the
physical storage of table data and associated index data, to
reduce storage space and improve I/O efficiency when accessing
the table. The exact changes made to each table depend on the
storage engine used
by that table.
Use OPTIMIZE TABLE in these
cases, depending on the type of table:
After doing substantial insert, update, or delete operations on an
InnoDBtable that has its own .ibd file because it was created with theinnodb_file_per_tableoption enabled. The table and indexes are reorganized, and disk space can be reclaimed for use by the operating system.After doing substantial insert, update, or delete operations on columns that are part of a
FULLTEXTindex in anInnoDBtable. Set the configuration optioninnodb_optimize_fulltext_only=1first. To keep the index maintenance period to a reasonable time, set theinnodb_ft_num_word_optimizeoption to specify how many words to update in the search index, and run a sequence ofOPTIMIZE TABLEstatements until the search index is fully updated.After deleting a large part of a
MyISAMorARCHIVEtable, or making many changes to aMyISAMorARCHIVEtable with variable-length rows (tables that haveVARCHAR,VARBINARY,BLOB, orTEXTcolumns). Deleted rows are maintained in a linked list and subsequentINSERToperations reuse old row positions. You can useOPTIMIZE TABLEto reclaim the unused space and to defragment the data file. After extensive changes to a table, this statement may also improve performance of statements that use the table, sometimes significantly.
This statement requires SELECT
and INSERT privileges for the
table.
OPTIMIZE TABLE works for
InnoDB,
MyISAM, and
ARCHIVE tables.
OPTIMIZE TABLE is also supported
for dynamic columns of in-memory
NDB tables. It does not work for
fixed-width columns of in-memory tables, nor does it work for
Disk Data tables. The performance of OPTIMIZE
on NDB Cluster tables can be tuned using
--ndb_optimization_delay, which
controls the length of time to wait between processing batches
of rows by OPTIMIZE TABLE. For
more information, see
Previous NDB Cluster Issues Resolved in NDB Cluster 7.3.
For NDB Cluster tables, OPTIMIZE
TABLE can be interrupted by (for example) killing the
SQL thread performing the OPTIMIZE operation.
By default, OPTIMIZE TABLE does
not work for tables created using any other
storage engine and returns a result indicating this lack of
support. You can make OPTIMIZE
TABLE work for other storage engines by starting
mysqld with the --skip-new
option. In this case, OPTIMIZE
TABLE is just mapped to ALTER
TABLE.
This statement does not work with views.
OPTIMIZE TABLE is supported for
partitioned tables. For information about using this statement
with partitioned tables and table partitions, see
Section 22.3.4, “Maintenance of Partitions”.
By default, the server writes OPTIMIZE
TABLE statements to the binary log so that they
replicate to replication slaves. To suppress logging, specify
the optional NO_WRITE_TO_BINLOG keyword or
its alias LOCAL.
OPTIMIZE TABLE returns a result
set with the columns shown in the following table.
| Column | Value |
|---|---|
Table | The table name |
Op | Always optimize |
Msg_type | status, error,
info, note, or
warning |
Msg_text | An informational message |
OPTIMIZE TABLE table catches
and throws any errors that occur while copying table
statistics from the old file to the newly created file. For
example. if the user ID of the owner of the
.frm, .MYD, or
.MYI file is different from the user ID
of the mysqld process,
OPTIMIZE TABLE generates a
"cannot change ownership of the file" error unless
mysqld is started by the
root user.
For InnoDB tables,
OPTIMIZE TABLE is mapped to
ALTER TABLE ...
FORCE, which rebuilds the table to update index
statistics and free unused space in the clustered index. This
is displayed in the output of OPTIMIZE
TABLE when you run it on an
InnoDB table, as shown here:
mysql> OPTIMIZE TABLE foo;
+----------+----------+----------+-------------------------------------------------------------------+
| Table | Op | Msg_type | Msg_text |
+----------+----------+----------+-------------------------------------------------------------------+
| test.foo | optimize | note | Table does not support optimize, doing recreate + analyze instead |
| test.foo | optimize | status | OK |
+----------+----------+----------+-------------------------------------------------------------------+
OPTIMIZE TABLE uses
online DDL for
regular and partitioned InnoDB tables,
which reduces downtime for concurrent DML operations. The
table rebuild triggered by OPTIMIZE
TABLE and performed under the cover by
ALTER TABLE ...
FORCE is completed in place. An exclusive table lock
is only taken briefly during the prepare phase and the commit
phase of the operation. During the prepare phase, metadata is
updated and an intermediate table is created. During the
commit phase, table metadata changes are committed.
OPTIMIZE TABLE rebuilds the
table using the table copy method under the following
conditions:
When the
old_alter_tablesystem variable is enabled.When the mysqld
--skip-newoption is enabled.
OPTIMIZE TABLE using
online DDL is not
supported for InnoDB tables that contain
FULLTEXT indexes. The table copy method is
used instead.
InnoDB stores data using a page-allocation
method and does not suffer from fragmentation in the same way
that legacy storage engines (such as
MyISAM) will. When considering whether or
not to run optimize, consider the workload of transactions
that your server will process:
Some level of fragmentation is expected.
InnoDBonly fills pages 93% full, to leave room for updates without having to split pages.Delete operations might leave gaps that leave pages less filled than desired, which could make it worthwhile to optimize the table.
Updates to rows usually rewrite the data within the same page, depending on the data type and row format, when sufficient space is available. See Section 14.9.1.5, “How Compression Works for InnoDB Tables” and Section 14.11.1, “Overview of InnoDB Row Storage”.
High-concurrency workloads might leave gaps in indexes over time, as
InnoDBretains multiple versions of the same data due through its MVCC mechanism. See Section 14.3, “InnoDB Multi-Versioning”.
For MyISAM tables,
OPTIMIZE TABLE works as
follows:
If the table has deleted or split rows, repair the table.
If the index pages are not sorted, sort them.
If the table's statistics are not up to date (and the repair could not be accomplished by sorting the index), update them.
OPTIMIZE TABLE is performed
online for regular and partitioned InnoDB
tables. Otherwise, MySQL locks
the table during the time OPTIMIZE
TABLE is running.
OPTIMIZE TABLE does not sort
R-tree indexes, such as spatial indexes on
POINT columns. (Bug #23578)
do a myisamchk on the table.
--
notice the deleted blocks in the right hand corner of the dialog. The stat still indicates a number > 0 for tables with deleted blocks.
===
myisamchk -r --sort-index --analyze *.MYI fixes that number. I'm inclined to believe the myisamchk *.MYI number since the table I'm "optimizing" does get a lot of deletes.
ALTER TABLE [tbl_name] TYPE=innodb
- will OPTIMIZE an INNODB table in the table space as well
alter table your_table row_format=compressed; to rebuild the table.
This means, that you need at least (database + data of biggest table) storage at the database directory (my case).
This may be very unfortunate, if you have (some, but) one very big table in your database, which needs almost all the storage... ;(
In this case, it is a very bad idea to optimize this table. Indeed, you can not optimize it, until the data of that big table is less then free space, which is very unlikely (This table must shrink to about eg. 1% its data).
Just tested: mysql will wait for space on the storage, if not enough is available for TABLE OPTIMIZE. Of course, this table will be locked all the time. I got out of this situation only by stopping the mysql server.
The only help I know, is to copy this table to another server with enough space, then optimized it there, and move this optimized table back (which must be done offline, because you have to remove the original first to get the space)
:: Set Global Variables
set mysqlbin=D:\hyperic\mysql-5.0.68\bin
set mysqlhost=localhost
set mysqlport=3306
set mysqluser=*
set mysqlpw=*
set target_data_free=10
:: sql cmd to get a list of fragmented tables
set get_fragtables=%mysqlbin%\mysql -h%mysqlhost% -P%mysqlport% -u%mysqluser% -p%mysqlpw% --batch -Dinformation_schema --skip-column-names -e "SELECT table_schema, table_name FROM TABLES where table_schema not in ('information_schema','mysql') and data_free > %target_data_free%;"
:: loop all fragmented tables and optimize.
for /f "tokens=1,2* delims= " %%A in ('%get_fragtables%') do (
echo %mysqlbin%\mysql -h%mysqlhost% -P%mysqlport% -u%mysqluser% -p%mysqlpw% --batch -e "optimize table %%A.%%B;"
)
Thus I wrote my own "optimize table" perl-script: it builds the table from scratch while it still can be used by other scripts through a merge-table solution.
Of course there are a few cave-ats: see the explanation in the script. But for us this script turned out to be very very useful. We could clean tables while we could still use them as if nothing was happening.
Basically it sets up a new MyISAM merge-table and a copy of the old table, and then starts to fill a newly created clean table with all data from the old un-optimized table. At some point all data has been moved and the switch back is made: removal of the merge-table and renaming of the new and optimized table to the appropriate table-name.
Here's the link to the script:
http://www.vosoft.nl/perl/reduce_table.pl.txt
http://camposer-techie.blogspot.com/2011/02/optimizando-tablas-innodb-en-mysql.html
Hope you find it useful (it's in spanish).
Delete operations leave the table fragmented as we all know. After a delete operation, inserts may go into table out of order unless you OPTIMIZE [table] after the delete operation, before inserting. If you OPTIMIZE after a delete, and before inserting, the new rows will appear in the expected order after insertion.
I usually have a sort order field when the order is important, when I design a schema, but in an existing schema without a sort field, this can be useful to know if the sort order is important and you don't want the additional risk of modifying the schema.