Speed of `INSERT' Queries
-------------------------
The time to insert a record consists approximately of:
* Connect: (3)
* Sending query to server: (2)
* Parsing query: (2)
* Inserting record: (1 x size of record)
* Inserting indexes: (1 x number of indexes)
* Close: (1)
where the numbers are somewhat proportional to the overall 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).
Some ways to speed up inserts:
* If you are inserting many rows from the same client at the same
time, use multiple value lists `INSERT' statements. This is much
faster (many times in some cases) than using separate `INSERT'
statements.
* If you are inserting a lot of rows from different clients, you can
get higher speed by using the `INSERT DELAYED' statement. Note:`INSERT'.
* Note that with `MyISAM' you can insert rows at the same time
`SELECT's are running if there are no deleted rows in the tables.
* When loading a table from a text file, use `LOAD DATA INFILE'. This
is usually 20 times faster than using a lot of `INSERT' statements.
Note:`LOAD DATA'.
* It is possible with some extra work to make `LOAD DATA INFILE' run
even faster when the table has many indexes. Use the following
procedure:
1. Optionally create the table with `CREATE TABLE'. For example,
using `mysql' or Perl-DBI.
2. Execute a `FLUSH TABLES' statement or the shell command
`mysqladmin flush-tables'.
3. Use `myisamchk --keys-used=0 -rq /path/to/db/tbl_name'. This
will remove all usage of all indexes from the table.
4. Insert data into the table with `LOAD DATA INFILE'. This will
not update any indexes and will therefore be very fast.
5. If you are going to only read the table in the future, run
`myisampack' on it to make it smaller. Note:Compressed
format.
6. Re-create the indexes with `myisamchk -r -q
/path/to/db/tbl_name'. This will create the index tree in
memory before writing it to disk, which is much faster
because it avoids lots of disk seeks. The resulting index
tree is also perfectly balanced.
7. Execute a `FLUSH TABLES' statement or the shell command
`mysqladmin flush-tables'.
This procedure will be built into `LOAD DATA INFILE' in some future
version of MySQL.
* You can speed up insertions by locking your tables:
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 an `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 for loading data.
To get some more speed for both `LOAD DATA INFILE' and `INSERT',
enlarge the key buffer. Note:Server parameters.