DOC HOME SITE MAP MAN PAGES GNU INFO SEARCH
 

(mysql.info.gz) Insert speed

Info Catalog (mysql.info.gz) How to avoid table scan (mysql.info.gz) Query Speed (mysql.info.gz) Update speed
 
 7.2.14 Speed of `INSERT' Statements
 -----------------------------------
 
 The time to insert a record is determined by the following factors,
 where the numbers indicate approximate proportions:
 
    * Connecting:              (3)
 
    * Sending query to server: (2)
 
    * Parsing query:           (2)
 
    * Inserting record:        (1 x size of record)
 
    * Inserting indexes:       (1 x 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 much faster (many times
      faster in some cases) than using separate single-row `INSERT'
      statements.  If you are adding data to a non-empty table, you may
      tune the `bulk_insert_buffer_size' variable to make it even faster.
       Server system variables.
 
    * If you are inserting a lot of rows from different clients, you can
      get higher speed by using the `INSERT DELAYED' statement. 
      `INSERT' INSERT.
 
    * With `MyISAM' tables you can insert rows at the same time that
      `SELECT' statements 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.
       `LOAD DATA' LOAD DATA.
 
    * With some extra work, it is possible 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'.
 
        2. Execute a `FLUSH TABLES' statement or a `mysqladmin
           flush-tables' command.
 
        3. Use `myisamchk --keys-used=0 -rq /PATH/TO/DB/TBL_NAME.' This
           will remove all use of all indexes for 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, use
           `myisampack' to make it smaller.  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 a `mysqladmin
           flush-tables' command.
 
 
      Note that `LOAD DATA INFILE' also performs the preceding
      optimization if you insert into an empty `MyISAM' table; the main
      difference is that you can let `myisamchk' allocate much more
      temporary memory for the index creation than you might want the
      server to allocate for index re-creation when it executes the
      `LOAD DATA INFILE' statement.
 
      As of MySQL 4.0, you can also use `ALTER TABLE TBL_NAME DISABLE
      KEYS' instead of `myisamchk --keys-used=0 -rq
      /PATH/TO/DB/TBL_NAME' and `ALTER TABLE TBL_NAME ENABLE KEYS'
      instead of `myisamchk -r -q /PATH/TO/DB/TBL_NAME'. This way you
      can also skip the `FLUSH TABLES' steps.
 
    * You can speed up `INSERT' operations that are done with multiple
      statements by locking your tables:
 
           LOCK TABLES a WRITE;
           INSERT INTO a VALUES (1,23),(2,34),(4,33);
           INSERT INTO a VALUES (8,26),(6,29);
           UNLOCK TABLES;
 
      A performance benefit occurs because 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. Explicit locking statements are not
      needed if you can insert all rows with a single statement.
 
      For transactional tables, you should use `BEGIN/COMMIT' instead of
      `LOCK TABLES' to get a speedup.
 
      Locking also lowers the total time of multiple-connection tests,
      although the maximum wait time for individual connections might go
      up because they wait for locks.  For example:
 
           Connection 1 does 1000 inserts
           Connections 2, 3, and 4 do 1 insert
           Connection 5 does 1000 inserts
 
      If you don't use locking, connections 2, 3, and 4 will finish
      before 1 and 5. If you use locking, connections 2, 3, and 4
      probably will not finish before 1 or 5, but the total time should
      be about 40% faster.
 
      `INSERT', `UPDATE', and `DELETE' operations are very fast in
      MySQL, but you will obtain better overall performance by adding
      locks around everything that does more than about five 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 1,000 rows) to allow other threads access to the
      table. This would still result in a nice performance gain.
 
      `INSERT' is still much slower for loading data than `LOAD DATA
      INFILE', even when using the strategies just outlined.
 
    * To get some more speed for `MyISAM' tables, for both `LOAD DATA
      INFILE' and `INSERT', enlarge the key cache by increasing the
      `key_buffer_size' system variable.   Server parameters.
 
 
Info Catalog (mysql.info.gz) How to avoid table scan (mysql.info.gz) Query Speed (mysql.info.gz) Update speed
automatically generated byinfo2html