Loading Data Efficiently

Most of the time you'll probably be concerned about optimizing SELECT queries because they are the most common type of query and because it's not always straightforward to figure out how to optimize them. By comparison, loading data into your database is straightforward. Nevertheless, there are strategies you can use to improve the efficiency of data-loading operations. The basic principles are as follows:

  • Bulk loading is more efficient than single-row loading because the index cache need not be flushed after each record is loaded; it can be flushed at the end of the batch of records. The more you can reduce index cache flushing, the faster data loading will be.

  • Loading is faster when a table has no indexes than when it is indexed. If there are indexes, not only must the record be added to the data file, but each index must also be modified to reflect the addition of the new record.

  • Shorter SQL statements are faster than longer statements because they involve less parsing on the part of the server and because they can be sent over the network from the client to the server more quickly.

Some of these factors may seem minor (the last one in particular), but if you're loading a lot of data, even small efficiencies make a difference. From the preceding general principles, several practical conclusions can be drawn about how to load data most quickly:

  • LOAD DATA (all forms) is more efficient than INSERT because it loads rows in bulk. Index flushing takes place less often, and the server needs to parse and interpret one statement, not several.

  • LOAD DATA is more efficient than LOAD DATA LOCAL. With LOAD DATA, the file must be located on the server and you must have the FILE privilege, but the server can read the file directly from disk. With LOAD DATA LOCAL, the client reads the file and sends it over the network to the server, which is slower.

  • If you must use INSERT, use the form that allows multiple rows to be specified in a single statement:

    INSERT INTO tbl_name VALUES(...),(...),... ; 
    

    The more rows you can specify in the statement, the better. This reduces the total number of statements you need and minimizes the amount of index flushing. This may seem to contradict the earlier remark that shorter statements can be processed faster than longer statements. But there is no contradiction. The principle here is that a single INSERT statement that inserts multiple rows is shorter overall than an equivalent set of individual single-row INSERT statements, and the multiple-row statement can be processed on the server with much less index flushing.

    If you use mysqldump to generate database backup files, use the --extended-insert option so that the dump file contains multiple-row INSERT statements. You can also use --opt (optimize), which turns on the --extended-insert option automatically, as well as some other options that allow the dump file to be processed more efficiently when it is reloaded. Conversely, avoid using the --complete-insert option with mysqldump; the resulting INSERT statements will be for single rows and will be longer and require more parsing than will statements generated without --complete-insert.

  • If you must use multiple INSERT statements, group them if possible to reduce index flushing. For transactional table types, do this by issuing the INSERT statements within a single transaction rather than in auto-commit mode:

    BEGIN; 
    INSERT INTO tbl_name ... ;
    INSERT INTO tbl_name ... ;
    INSERT INTO tbl_name ... ;
    COMMIT;
    

    For non-transactional table types, obtain a write lock on the table and issue the INSERT statements while the table is locked:

    LOCK TABLES tbl_name WRITE; 
    INSERT INTO tbl_name ... ;
    INSERT INTO tbl_name ... ;
    INSERT INTO tbl_name ... ;
    UNLOCK TABLES;
    

    You obtain the same benefit in both cases. The index is flushed once rather than once per INSERT statement, which is what happens in auto-commit mode or if the table has not been locked.

  • Use the compressed client/server protocol to reduce the amount of data going over the network. For most MySQL clients, this can be specified using the --compress command line option. Generally, this should only be used on slow networks because compression uses quite a bit of processor time.

  • Let MySQL insert default values for you. That is, don't specify columns in INSERT statements that will be assigned the default value anyway. On average, your statements will be shorter, reducing the number of characters sent over the network to the server. In addition, because the statements contain fewer values, the server does less parsing and value conversion.

  • If a table is indexed, you can lessen indexing overhead by using batched inserts (LOAD DATA or multiple-row INSERT statements). These minimize the impact of index updating because the index needs flushing only after all rows have been processed, rather than after each row.

  • For MyISAM and ISAM tables, if you need to load a lot of data into a new table to populate it, it's faster to create the table without indexes, load the data, and then create the indexes. It's faster to create the indexes all at once rather than to modify them for each row. For a table that already has indexes, data loading may be faster if you drop or deactivate the indexes beforehand and then rebuild or reactivate them afterward. These strategies do not apply to InnoDB or BDB tables, which do not have optimizations for separate index creation.

If you're considering using the strategy of dropping or deactivating indexes for loading data into MyISAM or ISAM tables, think about the overall circumstances of your situation in assessing whether any benefit is likely to be obtained. If you're loading a small amount of data into a large table, rebuilding the indexes probably will take longer than just loading the data without any special preparation.

To drop and rebuild indexes, use DROP INDEX and CREATE INDEX or the index-related forms of ALTER TABLE. To deactivate and reactivate indexes, you have two choices:

  • You can use the DISABLE KEYS and ENABLE KEYS forms of ALTER TABLE:

    ALTER TABLE tbl_name DISABLE KEYS; 
    ALTER TABLE tbl_name ENABLE KEYS;
    

    These statements turn off and on updating of any non-unique indexes in the table.

  • The myisamchk or isamchk utilities can perform index manipulation. These utilities operate directly on the table files, so to use them you must have write access to the table files. You should also observe the precautions described in Chapter 13 for keeping the server from accessing a table while you're using its files.

The DISABLE KEYS and ENABLE KEYS statements are the preferred method for index deactivation and activation because the server does the work. However, they are available only as of MySQL 4. (Note that if you're using LOAD DATA to load data into an empty MyISAM table, the server performs this optimization automatically.)

To deactivate a MyISAM table's indexes "manually," make sure you've told the server to leave the table alone and then move into the appropriate database directory and run the following command:

% myisamchk --keys-used=0 tbl_name 

After loading the table with data, reactivate the indexes:

% myisamchk --recover --quick --keys-used=n tbl_name 

n is interpreted as a bitmask indicating which indexes to enable. Bit 0 corresponds to index 1. For example, if a table has three indexes, the value of n should be 7 (111 binary). You can determine index numbers with the --description option:

% myisamchk --description tbl_name 

The commands for ISAM tables are similar except that you use isamchk rather than myisamchk, and the --keys-used value for isamchk indicates the highest-numbered index to use. (For a table with three indexes, n would be 3.)

The preceding data-loading principles also apply to mixed-query environments involving clients performing different kinds of operations. For example, you generally want to avoid long-running SELECT queries on tables that are changed (written to) frequently. This causes a lot of contention and poor performance for the writers. A possible way around this, if your writes are mostly INSERT operations, is to add new records to an auxiliary table and then add those records to the main table periodically. This is not a viable strategy if you need to be able to access new records immediately, but if you can afford to leave them inaccessible for a short time, use of the auxiliary table will help you two ways. First, it reduces contention with SELECT queries that are taking place on the main table, so they execute more quickly. Second, it takes less time overall to load a batch of records from the auxiliary table into the main table than it would to load the records individually; the index cache need be flushed only at the end of each batch rather than after each individual row.

One application for this strategy is when you're logging Web page accesses from your Web server into a MySQL database. In this case, it may not be a high priority to make sure the entries get into the main table right away.

For MyISAM tables, another strategy for reducing index flushing is to use the DELAYED_KEY_WRITE table creation option if your data are such that it's not absolutely essential that every single record be inserted in the event of abnormal system shutdown. (This might be the case if you're using MySQL for some sort of logging.) The option causes the index cache to be flushed only occasionally rather than after each insert. If you want to use delayed index flushing on a server-wide basis, start mysqld with the --delay-key-write option. In this case, index block writes for a table are delayed until blocks must be flushed to make room for other index values, until a flush-tables command has been executed, or until the table is closed.

For a replication slave server, you might want to use --delay-key-write=ALL to delay index flushing for all MyISAM tables, regardless of how they were created originally on the master server.