The time to insert a record consists of:
-
Connect: (3)
-
Sending query to server: (2)
-
Parsing query: (2)
-
Inserting record: (1 x size of record)
-
Inserting indexes: (1 x indexes)
-
Close: (1)
Where (number) is proportional time. 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 N log N
(B-trees).
You can speed up insertions by locking your table and/or using multiple value
lists with INSERT
statements. Using multiple value lists can be up to
5 times faster than using separate inserts.
mysql> LOCK TABLES a WRITE;
mysql> INSERT INTO a VALUES (1,23),(2,34),(4,33);
mysql> INSERT INTO a VALUES (8,26),(6,29);
mysql> UNLOCK TABLES;
The main speed difference is that the index buffer is flushed to disk only
once, after all INSERT
statements have completed. Normally there would
be as many index buffer flushes as there are different INSERT
statements. Locking is not needed if you can insert all rows with a single
statement.
Locking will also lower the total time of multi-connection tests, but the
maximum wait time for some threads will go up (because they wait for
locks). For example:
thread 1 does 1000 inserts
thread 2, 3, and 4 does 1 insert
thread 5 does 1000 inserts
If you don't use locking, 2, 3 and 4 will finish before 1 and 5. If you
use locking, 2, 3 and 4 probably will not finish before 1 or 5, but the
total time should be about 40% faster.
As INSERT
, UPDATE
and DELETE
operations are very fast in
MySQL, you will obtain better overall performance by adding locks
around everything that does more than about 5 inserts or updates in a row.
If you do very many inserts in a row, you could do a LOCK
TABLES
followed by a UNLOCK TABLES
once in a while (about each
1000 rows) to allow other threads access to the table. This would still
result in a nice performance gain.
Of course, LOAD DATA INFILE
is much faster still.
If you are inserting a lot of rows from different clients, you can get higher
speed by using the INSERT DELAYED
statement. INSERT
.