The first decisions to make about InnoDB
configuration involve the configuration of data files, log files,
and memory buffers. It is recommended that you define data file,
log file, and page size configuration before creating the
InnoDB instance. Modifying data file or log
file configuration after the InnoDB instance is
created may involve a non-trivial procedure.
In addition to these topics, this section provides information
about specifying InnoDB options in a
configuration file, viewing InnoDB
initialization information, and important storage considerations.
Because MySQL uses data file and log file configuration settings
to initialize the InnoDB instance, it is
recommended that you define these settings in a configuration
file that MySQL reads at startup, prior to initializing
InnoDB for the first time.
InnoDB is initialized when the MySQL server
is started, and the first initialization of
InnoDB normally occurs the first time you
start the MySQL server.
You can place InnoDB options in the
[mysqld] group of any option file that your
server reads when it starts. The locations of MySQL option files
are described in Section 4.2.6, “Using Option Files”.
To make sure that mysqld reads options only
from a specific file, use the
--defaults-file option as the
first option on the command line when starting the server:
mysqld --defaults-file=path_to_configuration_file
To view InnoDB initialization information
during startup, start mysqld from a command
prompt. When mysqld is started from a command
prompt, initialization information is printed to the console.
For example, on Windows, if mysqld is located
in C:\Program Files\MySQL\MySQL Server
5.5\bin, start the MySQL server like
this:
C:\> "C:\Program Files\MySQL\MySQL Server 5.5\bin\mysqld" --console
On Unix-like systems, mysqld is located in
the bin directory of your MySQL
installation:
sell> bin/mysqld --user=mysql &
If you do not send server output to the console, check the error
log after startup to see the initialization information
InnoDB printed during the startup process.
For information about starting MySQL using other methods, see Section 2.10.5, “Starting and Stopping MySQL Automatically”.
Review the following storage-related considerations before proceeding with your startup configuration.
In some cases, database performance improves if the data is not all placed on the same physical disk. Putting log files on a different disk from data is very often beneficial for performance. For example, you can place system tablespace data files and log files on different disks. You can also use raw disk partitions (raw devices) for
InnoDBdata files, which may speed up I/O. See Section 14.10.3, “Using Raw Disk Partitions for the System Tablespace”.InnoDBis a transaction-safe (ACID compliant) storage engine for MySQL that has commit, rollback, and crash-recovery capabilities to protect user data. However, it cannot do so if the underlying operating system or hardware does not work as advertised. Many operating systems or disk subsystems may delay or reorder write operations to improve performance. On some operating systems, the veryfsync()system call that should wait until all unwritten data for a file has been flushed might actually return before the data has been flushed to stable storage. Because of this, an operating system crash or a power outage may destroy recently committed data, or in the worst case, even corrupt the database because of write operations having been reordered. If data integrity is important to you, perform some “pull-the-plug” tests before using anything in production. On OS X 10.3 and higher,InnoDBuses a specialfcntl()file flush method. Under Linux, it is advisable to disable the write-back cache.On ATA/SATA disk drives, a command such
hdparm -W0 /dev/hdamay work to disable the write-back cache. Beware that some drives or disk controllers may be unable to disable the write-back cache.With regard to
InnoDBrecovery capabilities that protect user data,InnoDBuses a file flush technique involving a structure called the doublewrite buffer, which is enabled by default (innodb_doublewrite=ON). The doublewrite buffer adds safety to recovery following a crash or power outage, and improves performance on most varieties of Unix by reducing the need forfsync()operations. It is recommended that theinnodb_doublewriteoption remains enabled if you are concerned with data integrity or possible failures. For additional information about the doublewrite buffer, see Section 14.15.1, “InnoDB Disk I/O”.If reliability is a consideration for your data, do not configure
InnoDBto use data files or log files on NFS volumes. Potential problems vary according to OS and version of NFS, and include such issues as lack of protection from conflicting writes, and limitations on maximum file sizes.
System tablespace data files are configured using the
innodb_data_file_path and
innodb_data_home_dir
configuration options.
The innodb_data_file_path
configuration option is used to configure the
InnoDB system tablespace data files. The
value of innodb_data_file_path
should be a list of one or more data file specifications. If you
name more than one data file, separate them by semicolon
(;) characters:
innodb_data_file_path=datafile_spec1[;datafile_spec2]...
For example, the following setting explicitly creates a minimally sized system tablespace:
[mysqld] innodb_data_file_path=ibdata1:12M:autoextend
This setting configures a single 12MB data file named
ibdata1 that is auto-extending. No location
for the file is given, so by default, InnoDB
creates it in the MySQL data directory.
Sizes are specified using K,
M, or G suffix letters to
indicate units of KB, MB, or GB.
A tablespace containing a fixed-size 50MB data file named
ibdata1 and a 50MB auto-extending file
named ibdata2 in the data directory can be
configured like this:
[mysqld] innodb_data_file_path=ibdata1:50M;ibdata2:50M:autoextend
The full syntax for a data file specification includes the file name, its size, and several optional attributes:
file_name:file_size[:autoextend[:max:max_file_size]]
The autoextend and max
attributes can be used only for the last data file in the
innodb_data_file_path line.
If you specify the autoextend option for the
last data file, InnoDB extends the data file
if it runs out of free space in the tablespace. The increment is
64MB at a time by default. To modify the increment, change the
innodb_autoextend_increment
system variable.
If the disk becomes full, you might want to add another data file on another disk. For tablespace reconfiguration instructions, see Section 14.10.1, “Resizing the InnoDB System Tablespace”.
InnoDB is not aware of the file system
maximum file size, so be cautious on file systems where the
maximum file size is a small value such as 2GB. To specify a
maximum size for an auto-extending data file, use the
max attribute following the
autoextend attribute. Use the
max attribute only in cases where
constraining disk usage is of critical importance, because
exceeding the maximum size causes a fatal error, possibly
including a crash. The following configuration permits
ibdata1 to grow up to a limit of 500MB:
[mysqld] innodb_data_file_path=ibdata1:12M:autoextend:max:500M
InnoDB creates tablespace files in the MySQL
data directory by default
(datadir). To specify a
location explicitly, use the
innodb_data_home_dir option.
For example, to create two files named
ibdata1 and ibdata2 in
a directory named /myibdata, configure
InnoDB like this:
[mysqld] innodb_data_home_dir = /myibdata innodb_data_file_path=ibdata1:50M;ibdata2:50M:autoextend
InnoDB does not create directories, so make
sure that the /myibdata directory exists
before you start the server. Use the Unix or DOS
mkdir command to create any necessary
directories.
Make sure that the MySQL server has the proper access rights to create files in the data directory. More generally, the server must have access rights in any directory where it needs to create data files.
InnoDB forms the directory path for each data
file by textually concatenating the value of
innodb_data_home_dir to the
data file name, adding a path name separator (slash or
backslash) between values if necessary. If the
innodb_data_home_dir option is
not specified in my.cnf at all, the default
value is the “dot” directory
./, which means the MySQL data directory.
(The MySQL server changes its current working directory to its
data directory when it begins executing.)
If you specify
innodb_data_home_dir as an
empty string, you can specify absolute paths for the data files
listed in the
innodb_data_file_path value.
The following example is equivalent to the preceding one:
[mysqld] innodb_data_home_dir = innodb_data_file_path=/ibdata/ibdata1:50M;/ibdata/ibdata2:50M:autoextend
By default, InnoDB creates two 5MB log files
in the MySQL data directory
(datadir) named
ib_logfile0 and
ib_logfile1.
The following options can be used to modify the default configuration:
innodb_log_group_home_dirdefines directory path to theInnoDBlog files (the redo logs). If this option is not configured,InnoDBlog files are created in the MySQL data directory (datadir).You might use this option to place
InnoDBlog files in a different physical storage location thanInnoDBdata files to avoid potential I/O resource conflicts. For example:[mysqld] innodb_log_group_home_dir = /dr3/iblogs
NoteInnoDBdoes not create directories, so make sure that the log directory exists before you start the server. Use the Unix or DOSmkdircommand to create any necessary directories.Make sure that the MySQL server has the proper access rights to create files in the log directory. More generally, the server must have access rights in any directory where it needs to create log files.
innodb_log_files_in_groupdefines the number of log files in the log group. The default and recommended value is 2.innodb_log_file_sizedefines the size in bytes of each log file in the log group. The combined size of log files (innodb_log_file_size*innodb_log_files_in_group) cannot exceed a maximum value that is slightly less than 4GB. A pair of 2047 MB log files, for example, approaches the limit but does not exceed it. The default log file size is 5MB. Generally, the combined size of the log files should be large enough that the server can smooth out peaks and troughs in workload activity, which often means that there is enough redo log space to handle more than an hour of write activity. The larger the value, the less checkpoint flush activity is needed in the buffer pool, saving disk I/O. For additional information, see Section 8.5.3, “Optimizing InnoDB Redo Logging”.
MySQL allocates memory to various caches and buffers to improve
performance of database operations. When allocating memory for
InnoDB, always consider memory required by
the operating system, memory allocated to other applications,
and memory allocated for other MySQL buffers and caches. For
example, if you use MyISAM tables, consider
the amount of memory allocated for the key buffer
(key_buffer_size). For an
overview of MySQL buffers and caches, see
Section 8.12.4.1, “How MySQL Uses Memory”.
Buffers specific to InnoDB are configured
using the following parameters:
innodb_buffer_pool_sizedefines size of the buffer pool, which is the memory area that holds cached data forInnoDBtables, indexes, and other auxiliary buffers. The size of the buffer pool is important for system performance, and it is typically recommended thatinnodb_buffer_pool_sizeis configured to 50 to 75 percent of system memory. The default buffer pool size is 128MB. For additional guidance, see Section 8.12.4.1, “How MySQL Uses Memory”. For information about how to configureInnoDBbuffer pool size, see Configuring InnoDB Buffer Pool Size. Buffer pool size can be configured at startup.On systems with a large amount of memory, you can improve concurrency by dividing the buffer pool into multiple buffer pool instances. The number of buffer pool instances is controlled by the by
innodb_buffer_pool_instancesoption. By default,InnoDBcreates one buffer pool instance. The number of buffer pool instances can be configured at startup. For more information, see Section 14.9.2.2, “Configuring Multiple Buffer Pool Instances”.innodb_additional_mem_pool_sizedefines size in bytes of a memory poolInnoDBuses to store data dictionary information and other internal data structures. The more tables you have in your application, the more memory you allocate here. IfInnoDBruns out of memory in this pool, it starts to allocate memory from the operating system and writes warning messages to the MySQL error log. The default value is 8MB.innodb_log_buffer_sizedefines the size in bytes of the buffer thatInnoDBuses to write to the log files on disk. The default size is 8MB. A large log buffer enables large transactions to run without a need to write the log to disk before the transactions commit. If you have transactions that update, insert, or delete many rows, you might consider increasing the size of the log buffer to save disk I/O.innodb_log_buffer_sizecan be configured at startup. For related information, see Section 8.5.3, “Optimizing InnoDB Redo Logging”.
On 32-bit GNU/Linux x86, be careful not to set memory usage
too high. glibc may permit the process heap
to grow over thread stacks, which crashes your server. It is a
risk if the memory allocated to the mysqld
process for global and per-thread buffers and caches is close
to or exceeds 2GB.
A formula similar to the following that calculates global and per-thread memory allocation for MySQL can be used to estimate MySQL memory usage. You may need to modify the formula to account for buffers and caches in your MySQL version and configuration. For an overview of MySQL buffers and caches, see Section 8.12.4.1, “How MySQL Uses Memory”.
innodb_buffer_pool_size + key_buffer_size + max_connections*(sort_buffer_size+read_buffer_size+binlog_cache_size) + max_connections*2MB
Each thread uses a stack (often 2MB, but only 256KB in MySQL
binaries provided by Oracle Corporation.) and in the worst
case also uses sort_buffer_size +
read_buffer_size additional memory.
On Linux, if the kernel is enabled for large page support,
InnoDB can use large pages to allocate memory
for its buffer pool and additional memory pool. See
Section 8.12.4.2, “Enabling Large Page Support”.