REPLACE [LOW_PRIORITY | DELAYED] [INTO]tbl_name
[(col_name
,...)] {VALUES | VALUE} ({expr
| DEFAULT},...),(...),...
Or:
REPLACE [LOW_PRIORITY | DELAYED] [INTO]tbl_name
SETcol_name
={expr
| DEFAULT}, ...
Or:
REPLACE [LOW_PRIORITY | DELAYED] [INTO]tbl_name
[(col_name
,...)] SELECT ...
REPLACE
works exactly like
INSERT
, except that if an old row
in the table has the same value as a new row for a
PRIMARY KEY
or a UNIQUE
index, the old row is deleted before the new row is inserted. See
Section 12.2.4, “INSERT
Syntax”.
REPLACE
is a MySQL extension to the
SQL standard. It either inserts, or deletes
and inserts. For another MySQL extension to standard SQL —
that either inserts or updates — see
Section 12.2.4.3, “INSERT ... ON
DUPLICATE KEY UPDATE
Syntax”.
INSERT ... ON
DUPLICATE KEY UPDATE
is available as of MySQL 4.1.0.
Note that unless the table has a PRIMARY KEY
or
UNIQUE
index, using a
REPLACE
statement makes no sense.
It becomes equivalent to INSERT
,
because there is no index to be used to determine whether a new
row duplicates another.
Values for all columns are taken from the values specified in the
REPLACE
statement. Any missing
columns are set to their default values, just as happens for
INSERT
. You cannot refer to values
from the current row and use them in the new row. If you use an
assignment such as SET
, the reference
to the column name on the right hand side is treated as
col_name
=
col_name
+ 1DEFAULT(
,
so the assignment is equivalent to col_name
)SET
.
col_name
=
DEFAULT(col_name
) + 1
To use REPLACE
, you must have both
the INSERT
and
DELETE
privileges for the table.
The REPLACE
statement returns a
count to indicate the number of rows affected. This is the sum of
the rows deleted and inserted. If the count is 1 for a single-row
REPLACE
, a row was inserted and no
rows were deleted. If the count is greater than 1, one or more old
rows were deleted before the new row was inserted. It is possible
for a single row to replace more than one old row if the table
contains multiple unique indexes and the new row duplicates values
for different old rows in different unique indexes.
The affected-rows count makes it easy to determine whether
REPLACE
only added a row or whether
it also replaced any rows: Check whether the count is 1 (added) or
greater (replaced).
If you are using the C API, the affected-rows count can be
obtained using the
mysql_affected_rows()
function.
Currently, you cannot replace into a table and select from the same table in a subquery.
MySQL uses the following algorithm for
REPLACE
(and LOAD DATA ...
REPLACE
):
Try to insert the new row into the table
While the insertion fails because a duplicate-key error occurs for a primary key or unique index:
Delete from the table the conflicting row that has the duplicate key value
Try again to insert the new row into the table
User Comments
Be careful with InnoDB tables and REPLACE:
If you run a replace on existing keys on table T, and table F references T with a forgein key constraint ON DELETE CASCADE, then table T will be updated - but table F will be emptied due to the DELETE before INSERT.
e.g.:
CREATE TABLE T (
`id` int(10) unsigned NOT NULL auto_increment,
PRIMARY KEY (`id`)
);
CREATE TABLE F (
`foreign_id` int(10) unsigned NOT NULL,
CONSTRAINT `fkey` FOREIGN KEY (`foreign_id`) REFERENCES `T` (`id`) ON DELETE
CASCADE ON UPDATE CASCADE
);
<insert numbers 1..1000 into T>
<insert numbers 1..1000 into F>
REPLACE INTO T SELECT * FROM T;
=> T is updated
=> F is truncated - not the desired effect.
It is best to avoid REPLACE when working with constraints.
Be careful with REPLACE INTO with server side prepared statements and the 3.1.6 driver - it doesn't support them. The 3.0.x driver did :-(
Performance considerations:
Please note that REPLACE INTO is a much slower performer than an UPDATE statement. Keep in mind that a REPLACE INTO requires a test on the keys, and if a matching unique key is found on any or all columns, a DELETE FROM is executed, then an INSERT is executed. There's a lot of management of rows involved in this, and if you're doing it frequently, you'll hurt your performance unless you simply cannot do with any other syntax.
The only time when I can see where you'd actually need a REPLACE INTO is when you have multiple unique constraints on a table, and need to drop any rows that would match any of the constraints. Then REPLACE INTO becomes more efficient from DELETE FROM... INSERT INTO...
If you're looking at a single unique column table (Primary Key), please use UPDATE, or INSERT. Also, check out INSERT ... ON DUPLIATE KEY UPDATE... as an alternative if you're willing to stick to MySQL 4.1+
INNODB mysql 5.0 does not support "DELAYED" but does support LOW_PRIORITY :
mysql> REPLACE DELAYED INTO `online_users` SET `session_id`='3580cc4e61117c0785372c426eddd11c', `user_id` = 'XXX', `page` = '/', `lastview` = NOW();
ERROR 1031 (HY000): Table storage engine for 'online_users' doesn't have this option
PLEASE Note that the REPLACE does a DELETE operation.
We did not realize this and had the triggers that should be triggered on DELETE triggered.
After checking all the code, we just found a script that does a replace to refresh the values of some fields.
We should have had used "insert into ... on duplicate update" syntax instead.
If you are using REPLACE INTO... triggers are fired in this order (if delete of duplcate key is used):
- before insert
- before delete
- after delete
- after insert
This can also be used to merge databases http://serverprotectors.com/blog/64-merging-mysql-databases.html
Add your own comment.