MySQL :: MySQL 5.7 Reference Manual :: 14.8.1 InnoDB Startup Configuration (original) (raw)

14.8.1 InnoDB Startup Configuration

The first decisions to make about InnoDB configuration involve the configuration of data files, log files, page size, and memory buffers, which should be configured before initializing InnoDB. Modifying the configuration after InnoDB is initialized may involve non-trivial procedures.

This section provides information about specifyingInnoDB settings in a configuration file, viewing InnoDB initialization information, and important storage considerations.

Specifying Options in a MySQL Configuration File

Because MySQL uses data file, log file, and page size settings to initialize InnoDB, it is recommended that you define these settings in an option file that MySQL reads at startup, prior to initializing InnoDB. Normally, InnoDB is initialized when the MySQL server is started for the first time.

You can place InnoDB settings 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.2.2, “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_option_file

Viewing InnoDB Initialization Information

To view InnoDB initialization information during startup, start mysqld from a command prompt, which prints initialization information to the console.

For example, on Windows, if mysqld is located in C:\Program Files\MySQL\MySQL Server 5.7\bin, start the MySQL server like this:

C:\> "C:\Program Files\MySQL\MySQL Server 5.7\bin\mysqld" --console

On Unix-like systems, mysqld is located in the bin directory of your MySQL installation:

$> bin/mysqld --user=mysql &

If you do not send server output to the console, check the error log after startup to see the initialization informationInnoDB printed during the startup process.

For information about starting MySQL using other methods, seeSection 2.9.5, “Starting and Stopping MySQL Automatically”.

Note

InnoDB does not open all user tables and associated data files at startup. However,InnoDB does check for the existence of tablespace files referenced in the data dictionary. If a tablespace file is not found, InnoDB logs an error and continues the startup sequence. Tablespace files referenced in the redo log may be opened during crash recovery for redo application.

Important Storage Considerations

Review the following storage-related considerations before proceeding with your startup configuration.

System Tablespace Data File Configuration

The innodb_data_file_path option defines the name, size, and attributes ofInnoDB system tablespace data files. If you do not configure this option prior to initializing the MySQL server, the default behavior is to create a single auto-extending data file, slightly larger than 12MB, namedibdata1:

mysql> SHOW VARIABLES LIKE 'innodb_data_file_path';
+-----------------------+------------------------+
| Variable_name         | Value                  |
+-----------------------+------------------------+
| innodb_data_file_path | ibdata1:12M:autoextend |
+-----------------------+------------------------+

The full data file specification syntax includes the file name, file size, autoextend attribute, andmax attribute:

file_name:file_size[:autoextend[:max:max_file_size]]

File sizes are specified in kilobytes, megabytes, or gigabytes by appending K, M orG to the size value. If specifying the data file size in kilobytes, do so in multiples of 1024. Otherwise, kilobyte values are rounded to nearest megabyte (MB) boundary. The sum of file sizes must be, at a minimum, slightly larger than 12MB.

You can specify more than one data file using a semicolon-separated list. For example:

[mysqld]
innodb_data_file_path=ibdata1:50M;ibdata2:50M:autoextend

The autoextend and max attributes can be used only for the data file that is specified last.

When the autoextend attribute is specified, the data file automatically increases in size by 64MB increments as space is required. Theinnodb_autoextend_increment variable controls the increment size.

To specify a maximum size for an auto-extending data file, use the max attribute following theautoextend attribute. Use themax attribute only in cases where constraining disk usage is of critical importance. The following configuration permits ibdata1 to grow to a limit of 500MB:

[mysqld]
innodb_data_file_path=ibdata1:12M:autoextend:max:500M

A minimum file size is enforced for the_first_ system tablespace data file to ensure that there is enough space for doublewrite buffer pages. The following table shows minimum file sizes for eachInnoDB page size. The defaultInnoDB page size is 16384 (16KB).

Page Size (innodb_page_size) Minimum File Size
16384 (16KB) or less 3MB
32768 (32KB) 6MB
65536 (64KB) 12MB

If your disk becomes full, you can add a data file on another disk. For instructions, seeResizing the System Tablespace.

The size limit for individual files is determined by your operating system. You can set the file size to more than 4GB on operating systems that support large files. You can also use raw disk partitions as data files. SeeUsing Raw Disk Partitions for the 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.

System tablespace files are created in the data directory by default (datadir). To specify an alternate location, use theinnodb_data_home_dir option. For example, to create a system tablespace data file in a directory named myibdata, use this configuration:

[mysqld]
innodb_data_home_dir = /myibdata/
innodb_data_file_path=ibdata1:50M:autoextend

A trailing slash is required when specifying a value forinnodb_data_home_dir.InnoDB does not create directories, so ensure that the specified directory exists before you start the server. Also, ensure sure that the MySQL server has the proper access rights to create files in the directory.

InnoDB forms the directory path for each data file by textually concatenating the value ofinnodb_data_home_dir to the data file name. Ifinnodb_data_home_dir is not defined, the default value is “./”, which is the data directory. (The MySQL server changes its current working directory to the data directory when it begins executing.)

If you specifyinnodb_data_home_dir as an empty string, you can specify absolute paths for data files listed in theinnodb_data_file_path value. The following configuration is equivalent to the preceding one:

[mysqld]
innodb_data_home_dir =
innodb_data_file_path=/myibdata/ibdata1:50M:autoextend

Redo Log File Configuration

InnoDB creates two 5MB redo log files namedib_logfile0 andib_logfile1 in the data directory by default.

The following options can be used to modify the default configuration:

[mysqld]  
innodb_log_group_home_dir = /dr3/iblogs  

Note
InnoDB does not create directories, so make sure that the log 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 log directory. More generally, the server must have access rights in any directory where it needs to create log files.

Undo Tablespace Configuration

Undo logs are part of the system tablespace by default. However, you can choose to store undo logs in one or more separate undo tablespaces, typically on a different storage device.

The innodb_undo_directory configuration option defines the path whereInnoDB creates separate tablespaces for the undo logs. This option is typically used in conjunction with theinnodb_rollback_segments andinnodb_undo_tablespaces options, which determine the disk layout of the undo logs outside the system tablespace.

For more information, seeSection 14.6.3.4, “Undo Tablespaces”.

Temporary Tablespace Configuration

A single auto-extending temporary tablespace data file namedibtmp1 is created in theinnodb_data_home_dir directory by default. The initial file size is slightly larger than 12MB. The default temporary tablespace data file configuration can be modified at startup using theinnodb_temp_data_file_path configuration option.

The innodb_temp_data_file_path option specifies the path, file name, and file size for temporary tablespace data files. The full directory path is formed by concatenatinginnodb_data_home_dir to the path specified byinnodb_temp_data_file_path. File size is specified in KB, MB, or GB (1024MB) by appending K, M, or G to the size value. The file size or combined file size must be slightly larger than 12MB.

The innodb_data_home_dir default value is the MySQL data directory (datadir).

An autoextending temporary tablespace data file can become large in environments that use large temporary tables or that use temporary tables extensively. A large data file can also result from long running queries that use temporary tables. To prevent the temporary data file from becoming too large, configure theinnodb_temp_data_file_path option to specify a maximum data file size. For more information seeManaging Temporary Tablespace Data File Size.

Page Size Configuration

The innodb_page_size option specifies the page size for all InnoDB tablespaces in a MySQL instance. This value is set when the instance is created and remains constant afterward. Valid values are 64KB, 32KB, 16KB (the default), 8KB, and 4KB. Alternatively, you can specify page size in bytes (65536, 32768, 16384, 8192, 4096).

The default 16KB page size is appropriate for a wide range of workloads, particularly for queries involving table scans and DML operations involving bulk updates. Smaller page sizes might be more efficient for OLTP workloads involving many small writes, where contention can be an issue when a single page contains many rows. Smaller pages can also be more efficient for SSD storage devices, which typically use small block sizes. Keeping the InnoDB page size close to the storage device block size minimizes the amount of unchanged data that is rewritten to disk.

Important

innodb_page_size can be set only when initializing the data directory. See the description of this variable for more information.

Memory Configuration

MySQL allocates memory to various caches and buffers to improve performance of database operations. When allocating memory forInnoDB, 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, seeSection 8.12.4.1, “How MySQL Uses Memory”.

Buffers specific to InnoDB are configured using the following parameters:

Warning

On 32-bit GNU/Linux x86, if memory usage is set too high,glibc may permit the process heap to grow over the thread stacks, causing a server failure. 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. See Section 8.12.4.3, “Enabling Large Page Support”.