MySQL Restrictions and Limitations  /  Limits in MySQL  /  Limits on Table Size

8.3 Limits on Table Size

The effective maximum table size for MySQL databases is usually determined by operating system constraints on file sizes, not by MySQL internal limits. For up-to-date information operating system file size limits, refer to the documentation specific to your operating system.

Windows users, please note that FAT and VFAT (FAT32) are not considered suitable for production use with MySQL. Use NTFS instead.

If you encounter a full-table error, there are several reasons why it might have occurred:

  • The disk might be full.

  • You are using InnoDB tables and have run out of room in an InnoDB tablespace file. The maximum tablespace size is four billion pages (64TB), which is also the maximum size for a table. See Limits on InnoDB Tables.

    Generally, partitioning of tables into multiple tablespace files is recommended for tables larger than 1TB in size.

  • You have hit an operating system file size limit. For example, you are using MyISAM tables on an operating system that supports files only up to 2GB in size and you have hit this limit for the data file or index file.

  • You are using a MyISAM table and the space required for the table exceeds what is permitted by the internal pointer size. MyISAM permits data and index files to grow up to 256TB by default, but this limit can be changed up to the maximum permissible size of 65,536TB (2567 − 1 bytes).

    If you need a MyISAM table that is larger than the default limit and your operating system supports large files, the CREATE TABLE statement supports AVG_ROW_LENGTH and MAX_ROWS options. See CREATE TABLE Syntax. The server uses these options to determine how large a table to permit.

    If the pointer size is too small for an existing table, you can change the options with ALTER TABLE to increase a table's maximum permissible size. See ALTER TABLE Syntax.

    ALTER TABLE tbl_name MAX_ROWS=1000000000 AVG_ROW_LENGTH=nnn;
    

    You have to specify AVG_ROW_LENGTH only for tables with BLOB or TEXT columns; in this case, MySQL can't optimize the space required based only on the number of rows.

    To change the default size limit for MyISAM tables, set the myisam_data_pointer_size, which sets the number of bytes used for internal row pointers. The value is used to set the pointer size for new tables if you do not specify the MAX_ROWS option. The value of myisam_data_pointer_size can be from 2 to 7. A value of 4 permits tables up to 4GB; a value of 6 permits tables up to 256TB.

    You can check the maximum data and index sizes by using this statement:

    SHOW TABLE STATUS FROM db_name LIKE 'tbl_name';
    

    You also can use myisamchk -dv /path/to/table-index-file. See SHOW Syntax, or myisamchk — MyISAM Table-Maintenance Utility.

    Other ways to work around file-size limits for MyISAM tables are as follows:

    • If your large table is read only, you can use myisampack to compress it. myisampack usually compresses a table by at least 50%, so you can have, in effect, much bigger tables. myisampack also can merge multiple tables into a single table. See myisampack — Generate Compressed, Read-Only MyISAM Tables.

    • MySQL includes a MERGE library that enables you to handle a collection of MyISAM tables that have identical structure as a single MERGE table. See The MERGE Storage Engine.

  • You are using the NDB storage engine, in which case you need to increase the values for the DataMemory and IndexMemory configuration parameters in your config.ini file. See NDB Cluster Data Node Configuration Parameters.

  • You are using the MEMORY (HEAP) storage engine; in this case you need to increase the value of the max_heap_table_size system variable. See Server System Variables.


User Comments
Sign Up Login You must be logged in to post a comment.