INSERT DELAYED ...
The DELAYED option for the
INSERT statement is a MySQL
extension to standard SQL that is very useful if you have
clients that cannot or need not wait for the
INSERT to complete. This is a
common situation when you use MySQL for logging and you also
periodically run SELECT and
UPDATE statements that take a
long time to complete.
When a client uses INSERT
DELAYED, it gets an okay from the server at once, and
the row is queued to be inserted when the table is not in use by
any other thread.
Another major benefit of using INSERT
DELAYED is that inserts from many clients are bundled
together and written in one block. This is much faster than
performing many separate inserts.
Note that INSERT DELAYED is
slower than a normal INSERT if
the table is not otherwise in use. There is also the additional
overhead for the server to handle a separate thread for each
table for which there are delayed rows. This means that you
should use INSERT DELAYED only
when you are really sure that you need it.
The queued rows are held only in memory until they are inserted
into the table. This means that if you terminate
mysqld forcibly (for example, with
kill -9) or if mysqld dies
unexpectedly, any queued rows that have not been
written to disk are lost.
There are some constraints on the use of
DELAYED:
INSERT DELAYEDworks only withMyISAM,MEMORY,ARCHIVE, andBLACKHOLEtables. For engines that do not supportDELAYED, an error occurs.An error occurs for
INSERT DELAYEDif used with a table that has been locked withLOCK TABLESbecause the insert must be handled by a separate thread, not by the session that holds the lock.For
MyISAMtables, if there are no free blocks in the middle of the data file, concurrentSELECTandINSERTstatements are supported. Under these circumstances, you very seldom need to useINSERT DELAYEDwithMyISAM.INSERT DELAYEDshould be used only forINSERTstatements that specify value lists. The server ignoresDELAYEDforINSERT ... SELECTorINSERT ... ON DUPLICATE KEY UPDATEstatements.Because the
INSERT DELAYEDstatement returns immediately, before the rows are inserted, you cannot useLAST_INSERT_ID()to get theAUTO_INCREMENTvalue that the statement might generate.DELAYEDrows are not visible toSELECTstatements until they actually have been inserted.Prior to MySQL 5.5.7,
INSERT DELAYEDwas treated as a normalINSERTif the statement inserted multiple rows, binary logging was enabled, and the global logging format was statement-based (that is, wheneverbinlog_formatwas set toSTATEMENT). Beginning with MySQL 5.5.7,INSERT DELAYEDis always handled as a simpleINSERT(that is, without theDELAYEDoption) whenever the value ofbinlog_formatisSTATEMENTorMIXED. (In the latter case, the statement no longer triggers a switch to row-based logging, and so is logged using the statement-based format.)This does not apply when using row-based binary logging mode (
binlog_formatset toROW), in whichINSERT DELAYEDstatements are always executed using theDELAYEDoption as specified, and logged as row-update events.DELAYEDis ignored on slave replication servers, so thatINSERT DELAYEDis treated as a normalINSERTon slaves. This is becauseDELAYEDcould cause the slave to have different data than the master.Pending
INSERT DELAYEDstatements are lost if a table is write locked andALTER TABLEis used to modify the table structure.INSERT DELAYEDis not supported for views.INSERT DELAYEDis not supported for partitioned tables.
The following describes in detail what happens when you use the
DELAYED option to
INSERT or
REPLACE. In this description, the
“thread” is the thread that received an
INSERT DELAYED statement and
“handler” is the thread that handles all
INSERT DELAYED statements for a
particular table.
When a thread executes a
DELAYEDstatement for a table, a handler thread is created to process allDELAYEDstatements for the table, if no such handler already exists.The thread checks whether the handler has previously acquired a
DELAYEDlock; if not, it tells the handler thread to do so. TheDELAYEDlock can be obtained even if other threads have aREADorWRITElock on the table. However, the handler waits for allALTER TABLElocks orFLUSH TABLESstatements to finish, to ensure that the table structure is up to date.The thread executes the
INSERTstatement, but instead of writing the row to the table, it puts a copy of the final row into a queue that is managed by the handler thread. Any syntax errors are noticed by the thread and reported to the client program.The client cannot obtain from the server the number of duplicate rows or the
AUTO_INCREMENTvalue for the resulting row, because theINSERTreturns before the insert operation has been completed. (If you use the C API, themysql_info()function does not return anything meaningful, for the same reason.)The binary log is updated by the handler thread when the row is inserted into the table. In case of multiple-row inserts, the binary log is updated when the first row is inserted.
Each time that
delayed_insert_limitrows are written, the handler checks whether anySELECTstatements are still pending. If so, it permits these to execute before continuing.When the handler has no more rows in its queue, the table is unlocked. If no new
INSERT DELAYEDstatements are received withindelayed_insert_timeoutseconds, the handler terminates.If more than
delayed_queue_sizerows are pending in a specific handler queue, the thread requestingINSERT DELAYEDwaits until there is room in the queue. This is done to ensure that mysqld does not use all memory for the delayed memory queue.The handler thread shows up in the MySQL process list with
delayed_insertin theCommandcolumn. It is killed if you execute aFLUSH TABLESstatement or kill it withKILL. However, before exiting, it first stores all queued rows into the table. During this time it does not accept any newthread_idINSERTstatements from other threads. If you execute anINSERT DELAYEDstatement after this, a new handler thread is created.Note that this means that
INSERT DELAYEDstatements have higher priority than normalINSERTstatements if there is anINSERT DELAYEDhandler running. Other update statements have to wait until theINSERT DELAYEDqueue is empty, someone terminates the handler thread (withKILL), or someone executes athread_idFLUSH TABLES.The following status variables provide information about
INSERT DELAYEDstatements.Status Variable Meaning Delayed_insert_threadsNumber of handler threads Delayed_writesNumber of rows written with INSERT DELAYEDNot_flushed_delayed_rowsNumber of rows waiting to be written You can view these variables by issuing a
SHOW STATUSstatement or by executing a mysqladmin extended-status command.