MySQL 8.4 Reference Manual Including MySQL NDB Cluster 8.4
To optimize insert speed, combine many small operations into a single large operation. Ideally, you make a single connection, send the data for many new rows at once, and delay all index updates and consistency checking until the very end.
The time required for inserting a row is determined by the following factors, where the numbers indicate approximate proportions:
Connecting: (3)
Sending query to server: (2)
Parsing query: (2)
Inserting row: (1 × size of row)
Inserting indexes: (1 × number of indexes)
Closing: (1)
This does not take into consideration the initial overhead to open tables, which is done once for each concurrently running query.
The size of the table slows down the insertion of indexes by
log N
, assuming B-tree indexes.
You can use the following methods to speed up inserts:
If you are inserting many rows from the same client at the
same time, use INSERT
statements with multiple VALUES
lists
to insert several rows at a time. This is considerably
faster (many times faster in some cases) than using
separate single-row INSERT
statements. If you are adding data to a nonempty table,
you can tune the
bulk_insert_buffer_size
variable to make data insertion even faster. See
Section 7.1.8, “Server System Variables”.
When loading a table from a text file, use
LOAD DATA
. This is usually
20 times faster than using
INSERT
statements. See
Section 15.2.9, “LOAD DATA Statement”.
Take advantage of the fact that columns have default values. Insert values explicitly only when the value to be inserted differs from the default. This reduces the parsing that MySQL must do and improves the insert speed.
See Section 10.5.5, “Bulk Data Loading for InnoDB Tables”
for tips specific to InnoDB
tables.
See Section 10.6.2, “Bulk Data Loading for MyISAM Tables”
for tips specific to MyISAM
tables.