Pre-General Availability Draft: 2017-07-17
[+/-]
INSERT [LOW_PRIORITY | DELAYED | HIGH_PRIORITY] [IGNORE]
[INTO] tbl_name
[PARTITION (partition_name,...)]
[(col_name,...)]
{VALUES | VALUE} ({expr | DEFAULT},...),(...),...
[ ON DUPLICATE KEY UPDATE
col_name=expr
[, col_name=expr] ... ]Or:
INSERT [LOW_PRIORITY | DELAYED | HIGH_PRIORITY] [IGNORE]
[INTO] tbl_name
[PARTITION (partition_name,...)]
SET col_name={expr | DEFAULT}, ...
[ ON DUPLICATE KEY UPDATE
col_name=expr
[, col_name=expr] ... ]Or:
INSERT [LOW_PRIORITY | HIGH_PRIORITY] [IGNORE]
[INTO] tbl_name
[PARTITION (partition_name,...)]
[(col_name,...)]
SELECT ...
[ ON DUPLICATE KEY UPDATE
col_name=expr
[, col_name=expr] ... ]
INSERT inserts new rows into an
existing table. The INSERT
... VALUES and
INSERT ... SET
forms of the statement insert rows based on explicitly specified
values. The INSERT
... SELECT form inserts rows selected from another table
or tables. INSERT
... SELECT is discussed further in
Section 13.2.6.1, “INSERT ... SELECT Syntax”.
When inserting into a partitioned table, you can control which
partitions and subpartitions accept new rows. The
PARTITION option takes a comma-separated list
of the names of one or more partitions or subpartitions (or both)
of the table. If any of the rows to be inserted by a given
INSERT statement do not match one of the
partitions listed, the INSERT statement fails
with the error Found a row not matching the given
partition set. See
Section 22.5, “Partition Selection”, for more information and
examples.
In MySQL 8.0, the DELAYED keyword
is accepted but ignored by the server. See
Section 13.2.6.2, “INSERT DELAYED Syntax”, for the reasons for this.
You can use REPLACE instead of
INSERT to overwrite old rows.
REPLACE is the counterpart to
INSERT IGNORE in
the treatment of new rows that contain unique key values that
duplicate old rows: The new rows are used to replace the old rows
rather than being discarded. See Section 13.2.9, “REPLACE Syntax”.
tbl_name is the table into which rows
should be inserted. The columns for which the statement provides
values can be specified as follows:
You can provide a comma-separated list of column names following the table name. In this case, a value for each named column must be provided by the
VALUESlist or theSELECTstatement.If you do not specify a list of column names for
INSERT ... VALUESorINSERT ... SELECT, values for every column in the table must be provided by theVALUESlist or theSELECTstatement. If you do not know the order of the columns in the table, useDESCRIBEto find out.tbl_nameThe
SETclause indicates the column names explicitly.
Column values can be given in several ways:
If you are not running in strict SQL mode, any column not explicitly given a value is set to its default (explicit or implicit) value. For example, if you specify a column list that does not name all the columns in the table, unnamed columns are set to their default values. Default value assignment is described in Section 11.7, “Data Type Default Values”. See also Section 1.8.3.3, “Constraints on Invalid Data”.
If you want an
INSERTstatement to generate an error unless you explicitly specify values for all columns that do not have a default value, you should use strict mode. See Section 5.1.8, “Server SQL Modes”.Use the keyword
DEFAULTto set a column explicitly to its default value. This makes it easier to writeINSERTstatements that assign values to all but a few columns, because it enables you to avoid writing an incompleteVALUESlist that does not include a value for each column in the table. Otherwise, you would have to write out the list of column names corresponding to each value in theVALUESlist.You can also use
DEFAULT(as a more general form that can be used in expressions to produce a given column's default value.col_name)If both the column list and the
VALUESlist are empty,INSERTcreates a row with each column set to its default value:INSERT INTO tbl_name () VALUES();In strict mode, an error occurs if any column doesn't have a default value. Otherwise, MySQL uses the implicit default value for any column that does not have an explicitly defined default.
You can specify an expression
exprto provide a column value. This might involve type conversion if the type of the expression does not match the type of the column, and conversion of a given value can result in different inserted values depending on the data type. For example, inserting the string'1999.0e-2'into anINT,FLOAT,DECIMAL(10,6), orYEARcolumn results in the values1999,19.9921,19.992100, and1999being inserted, respectively. The reason the value stored in theINTandYEARcolumns is1999is that the string-to-integer conversion looks only at as much of the initial part of the string as may be considered a valid integer or year. For the floating-point and fixed-point columns, the string-to-floating-point conversion considers the entire string a valid floating-point value.An expression
exprcan refer to any column that was set earlier in a value list. For example, you can do this because the value forcol2refers tocol1, which has previously been assigned:INSERT INTO tbl_name (col1,col2) VALUES(15,col1*2);But the following is not legal, because the value for
col1refers tocol2, which is assigned aftercol1:INSERT INTO tbl_name (col1,col2) VALUES(col2*2,15);One exception involves columns that contain
AUTO_INCREMENTvalues. Because theAUTO_INCREMENTvalue is generated after other value assignments, any reference to anAUTO_INCREMENTcolumn in the assignment returns a0.
INSERT statements that use
VALUES syntax can insert multiple rows. To do
this, include multiple lists of column values, each enclosed
within parentheses and separated by commas. Example:
INSERT INTO tbl_name (a,b,c) VALUES(1,2,3),(4,5,6),(7,8,9);The values list for each row must be enclosed within parentheses. The following statement is illegal because the number of values in the list does not match the number of column names:
INSERT INTO tbl_name (a,b,c) VALUES(1,2,3,4,5,6,7,8,9);
VALUE is a synonym for
VALUES in this context. Neither implies
anything about the number of values lists, and either may be used
whether there is a single values list or multiple lists.
The affected-rows value for an
INSERT can be obtained using the
ROW_COUNT() function (see
Section 12.14, “Information Functions”), or the
mysql_affected_rows() C API
function (see Section 27.7.7.1, “mysql_affected_rows()”).
If you use an INSERT ...
VALUES statement with multiple value lists or
INSERT ...
SELECT, the statement returns an information string in
this format:
Records: 100 Duplicates: 0 Warnings: 0
Records indicates the number of rows processed
by the statement. (This is not necessarily the number of rows
actually inserted because Duplicates can be
nonzero.) Duplicates indicates the number of
rows that could not be inserted because they would duplicate some
existing unique index value. Warnings indicates
the number of attempts to insert column values that were
problematic in some way. Warnings can occur under any of the
following conditions:
Inserting
NULLinto a column that has been declaredNOT NULL. For multiple-rowINSERTstatements orINSERT INTO ... SELECTstatements, the column is set to the implicit default value for the column data type. This is0for numeric types, the empty string ('') for string types, and the “zero” value for date and time types.INSERT INTO ... SELECTstatements are handled the same way as multiple-row inserts because the server does not examine the result set from theSELECTto see whether it returns a single row. (For a single-rowINSERT, no warning occurs whenNULLis inserted into aNOT NULLcolumn. Instead, the statement fails with an error.)Setting a numeric column to a value that lies outside the column's range. The value is clipped to the closest endpoint of the range.
Assigning a value such as
'10.34 a'to a numeric column. The trailing nonnumeric text is stripped off and the remaining numeric part is inserted. If the string value has no leading numeric part, the column is set to0.Inserting a string into a string column (
CHAR,VARCHAR,TEXT, orBLOB) that exceeds the column's maximum length. The value is truncated to the column's maximum length.Inserting a value into a date or time column that is illegal for the data type. The column is set to the appropriate zero value for the type.
If a generated column is inserted into explicitly, the only
permitted value is DEFAULT. For information
about generated columns, see
Section 13.1.15.8, “CREATE TABLE and Generated Columns”.
If you are using the C API, the information string can be obtained
by invoking the mysql_info()
function. See Section 27.7.7.36, “mysql_info()”.
If INSERT inserts a row into a
table that has an AUTO_INCREMENT column, you
can find the value used for that column by using the SQL
LAST_INSERT_ID() function. From
within the C API, use the
mysql_insert_id() function.
However, you should note that the two functions do not always
behave identically. The behavior of
INSERT statements with respect to
AUTO_INCREMENT columns is discussed further in
Section 12.14, “Information Functions”, and
Section 27.7.7.38, “mysql_insert_id()”.
The INSERT statement supports the
following modifiers:
INSERT DELAYEDwas deprecated in MySQL 5.7, and is scheduled for eventual removal. In MySQL 8.0, theDELAYEDmodifier is accepted but ignored. UseINSERT(withoutDELAYED) instead. See Section 13.2.6.2, “INSERT DELAYED Syntax”.If you use the
LOW_PRIORITYmodifier, execution of theINSERTis delayed until no other clients are reading from the table. This includes other clients that began reading while existing clients are reading, and while theINSERT LOW_PRIORITYstatement is waiting. It is possible, therefore, for a client that issues anINSERT LOW_PRIORITYstatement to wait for a very long time.NoteLOW_PRIORITYshould normally not be used withMyISAMtables because doing so disables concurrent inserts. See Section 8.11.3, “Concurrent Inserts”.If you specify
HIGH_PRIORITY, it overrides the effect of the--low-priority-updatesoption if the server was started with that option. It also causes concurrent inserts not to be used. See Section 8.11.3, “Concurrent Inserts”.LOW_PRIORITYandHIGH_PRIORITYaffect only storage engines that use only table-level locking (such asMyISAM,MEMORY, andMERGE).If you use the
IGNOREmodifier, errors that occur while executing theINSERTstatement are ignored. For example, withoutIGNORE, a row that duplicates an existingUNIQUEindex orPRIMARY KEYvalue in the table causes a duplicate-key error and the statement is aborted. WithIGNORE, the row is discarded and no error occurs. Ignored errors generate warnings instead.IGNOREhas a similar effect on inserts into partitioned tables where no partition matching a given value is found. WithoutIGNORE, suchINSERTstatements are aborted with an error; however, whenINSERT IGNOREis used, the insert operation fails silently for the row containing the unmatched value, but any rows that are matched are inserted. For an example, see Section 22.2.2, “LIST Partitioning”.Data conversions that would trigger errors abort the statement if
IGNOREis not specified. WithIGNORE, invalid values are adjusted to the closest values and inserted; warnings are produced but the statement does not abort. You can determine with themysql_info()C API function how many rows were actually inserted into the table.For more information, see Comparison of the IGNORE Keyword and Strict SQL Mode.
If you specify
ON DUPLICATE KEY UPDATE, and a row is inserted that would cause a duplicate value in aUNIQUEindex orPRIMARY KEY, anUPDATEof the old row is performed. The affected-rows value per row is 1 if the row is inserted as a new row, 2 if an existing row is updated, and 0 if an existing row is set to its current values. If you specify theCLIENT_FOUND_ROWSflag tomysql_real_connect()when connecting to mysqld, the affected-rows value is 1 (not 0) if an existing row is set to its current values. See Section 13.2.6.3, “INSERT ... ON DUPLICATE KEY UPDATE Syntax”.
Inserting into a table requires the
INSERT privilege for the table. If
the ON DUPLICATE KEY UPDATE clause is used and
a duplicate key causes an UPDATE to
be performed instead, the statement requires the
UPDATE privilege for the columns to
be updated. For columns that are read but not modified you need
only the SELECT privilege (such as
for a column referenced only on the right hand side of an
col_name=expr
assignment in an ON DUPLICATE KEY UPDATE
clause).
In MySQL 8.0, an INSERT statement
affecting a partitioned table using a storage engine such as
MyISAM that employs table-level locks
locks only those partitions into which rows are actually inserted.
(For storage engines such as InnoDB
that employ row-level locking, no locking of partitions takes
place.) For more information, see
Partitioning and Locking.
Here's an example:
insert into Citylist (cityname) VALUES ('St. John\'s')
If you have a log table to log hits to different websites daily, with "site_id"-s and "time" fields, where neither of them are primary keys, but togethether they are unique, then you can create a key on them, and then use "...ON DUPLICATE KEY..."
Table logs:
id: INT(11) auto_increment primary key
site_id: INT(11)
time: DATE
hits: INT(11)
Then:
CREATE UNIQUE INDEX comp ON logs (`site_id`, `time`);
And then you can:
INSERT INTO logs (`site_id`, `time`,`hits`) VALUES (1,"2004-08-09", 15) ON DUPLICATE KEY UPDATE hits=hits+15;
Excellent feature, and it is much faster and briefer then using first a select, then issuing either an update or an insert depending on the value of the select. You also get rid of the probably necessary table-lock during this action.
1 for each successful INSERT.
2 for each successful UPDATE.
For example, if you insert 5 rows with this syntax, and 3 of them were inserted while 2 were updated, the return value would be 7:
((3 inserts * 1) + (2 updates * 2)) = 7.
The return value may at first appear worrisome, as only 5 rows in the table were actually modified, but actually provides more information, because you can determine the quantities of each query type performed from the return value.
For further information, see:
http://bugs.mysql.com/bug.php?id=2709
Le code suivant permet de créer une nouvelle table appelée "fusion" avec les champs partition en, classe, segment, F tot, F loc et indice specif.
CREATE TABLE `fusion` (
`partition en` VARCHAR( 11 ) NOT NULL,
`classe` VARCHAR( 11 ) NOT NULL,
`segment` TEXT NOT NULL ,
`F tot` INT NOT NULL ,
`F loc` INT NOT NULL ,
`indice specif` INT NOT NULL
);
On peut mettre à la suite de ce code, le code suivant autant de fois que voulu qui permet de fusionner les tables dans la nouvelle table "fusion":
INSERT INTO l4stal13prema00.`fusion` ( `partition en` ,
`classe` ,
`segment` ,
`F tot` ,
`F loc` ,
`indice specif` )
SELECT *
FROM f3p1
WHERE 1;
INSERT INTO l4stal13prema00.`fusion` ( `partition en` ,
`classe` ,
`segment` ,
`F tot` ,
`F loc` ,
`indice specif` )
SELECT *
FROM f3p2
WHERE 1;
http://dev.mysql.com/doc/mysql/en/Counting_rows.html
If you know another way when inserting several files with almost the same data (cat dog turtle + cat dog parrot= cat dog turtle parrot) and avoid repetition, tell it please?
If you do this then SELECT LAST_INSERT_ID() will return either the inserted id or the updated id.
CREATE TABLE t1 (
a INT NOT NULL AUTO_INCREMENT PRIMARY KEY,
b VARCHAR(10)) TYPE=InnoDB;
INSERT INTO t1 (b) VALUES ('Spike'), ('Chip'), ('John');
CREATE TABLE t2 (
a INT NOT NULL AUTO_INCREMENT PRIMARY KEY,
b INT NOT NULL,
FOREIGN KEY (b) REFERENCES t1 (a),
c VARCHAR(15)) TYPE=InnoDB;
We can INSERT rows into t2 that populate the foreign key column based on a SELECT statement on t1:
INSERT INTO t2 (b, c)
VALUES ((SELECT a FROM t1 WHERE b='Chip'), 'shoulder'),
((SELECT a FROM t1 WHERE b='Chip'), 'old block'),
((SELECT a FROM t1 WHERE b='John'), 'toilet'),
((SELECT a FROM t1 WHERE b='John'), 'long,silver'),
((SELECT a FROM t1 WHERE b='John'), 'li''l');
Then we get:
mysql> SELECT * FROM t2;
5 rows in set (0.00 sec)
This is especially useful if you don't want to specify the ids for your rows (because they may differ from database to database, due to their being based on AUTO_INCREMENTs), but you want to refer to the values of other tables.
I haven't tested this to determine the version of MySQL this was introduced into, or whether it is necessary that the tables be InnoDB, but it works on my boxes (MySQL 4.1.12)
1) Create an empty column in the tableA:
ALTER TABLE tableA ADD color CHAR(20);
2) If you don't have an auto-incrementation in the two tables (tableB for exemple):
ALTER TABLE tableB ADD (id INT AUTO_INCREMENT NOT NULL, PRIMARY KEY(id));
3) Fill the columns with the values:
UPDATE tableA,tableB SET tableA.color=tableB.color WHERE tableA.id=tableB.id;
INSERT INTO TargetTable (col1, col2, col3)
SELECT col1,col2,col3
FROM SourceTable JOIN (SELECT 'ExplicitValue' AS col3) AS AnyAlias
This looks quite simple but it took me several hours to understand that there's no need for a special statement to handle such cases.
Regards!
> INSERT INTO TargetTable (col1, col2, col3)
> SELECT col1,col2,col3
> FROM SourceTable
> JOIN (SELECT 'ExplicitValue' AS col3) AS AnyAlias
You could easily do the same thing just by using:
INSERT INTO TargetTable (col1, col2, col3)
SELECT col1,col2, 'ExplicitValue'
FROM SourceTable
hth,
Lokar
INSERT INTO tbl_test (FirstName)
SELECT 'Aleem'
UNION ALL
SELECT 'Latif'
UNION ALL
SELECT 'Mughal'
PHP code below outputs:
r==1
r==0
Cheers, al.
INSERT INTO prod_table
(col1,
col2,
col3
)
SELECT * FROM bkup_table;
Hope this helps somebody.
if one of the source table is based on Innodb engine.
It is also possible that the INSERT activity applicable to TEMPORARY
table which is not InnoDB engine. It is also possible that in SELECT
section with INNODB, some other TEMPORARY Tables are used.
Devang Modi
INSERT INTO users VALUES (userid='billgates', password='someword', name='Bill Gates', telephone='480-456-9344') ON DUPLICATE KEY UPDATE userid='billgates';
This record will not be inserted as the username is already in the database other fields can be used.
Regards,
Elliot
http://www.sioure.com
For example, take these tables:
CREATE TABLE t1 (
a INT NOT NULL AUTO_INCREMENT PRIMARY KEY,
b INT NOT NULL,
c VARCHAR(15)) ENGINE=ndbluster;
CREATE TABLE t2 (
a INT NOT NULL AUTO_INCREMENT PRIMARY KEY,
b INT NOT NULL,
c VARCHAR(15)) ENGINE=ndbluster;
And this psuedocode running on NDB node 3:
int b=0;
while (b<1000) {
INSERT INTO t1 (b,c) VALUES ($b,”Node 3”);
b++;
sleep(1);
}
This psuedocode running on NDB node 4:
int b=0;
while (b<1000) {
for (int x=0;x<10; x++) {
INSERT INTO t2(b,c) VALUES ($b,”Node 4”);
b++;
sleep(1);
}
INSERT INTO t1(b,c) SELECT (b,c) FROM t2;
DELETE FROM t2;
}
This will result in holes that are backfilled in t1. After a run, this would be the first 100 rows of
SELECT * FROM t1 ORDER BY a;
---------------------------------
---------------------------------
…
SELECT MAX(a) FROM t1;
will return 2008 as the highest “in use” a value, even though the table would have only 2000 actual results.
This has serious implications for using a as a High Water Mark; because node 4 “backfilled” t1 (node 3 jumped from inserting into a=9 to a=42 above, and from a=71 to a=104), the HWM will miss node4 values. This is a direct result of behavior modified for bug 31956:
ndb_autoincrement_prefetch_sz to specify prefetch between statements, changed default to1 (with internal prefetch to at least 32 inside a statement), added handling of updates of pk/unique key with auto_increment
Becasue an Insert-Select does not know how many rows will be returned, 32 rows will be allocated, and will continue to be used until exhausted, regardless of if 10 rows at a time are moved, or 1 (if x had only been allowed to grow to 1, for example, a=1 would have had 'Node 4' while the second 'Node 3' row would have been a=33). Therefore, it is NOT recommended to use Insert-Select statements with Cluster databases if the auto-incrementing ID is meant to imply an absolute order on the timing of insertion into a table. The developer will need to explicitly pull out each row from t2 and insert them individually into t1 for the desired effect.
If one column of the unique key is null, then no duplicate-error is catch, and duplicate entry can be inserted.
For example, you have a unique key (`id`, `second`), but the `second` is null when inserted:
drop table if exists import_temp.test;
create table import_temp.test(
`id` int(11) NOT NULL,
`second` int DEFAULT NULL,
UNIQUE KEY `i` (`id`, `second`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
insert into import_temp.test(id, second)
values(1, null);
insert ignore into import_temp.test(id, second)
values(1, null);
then you have 2 entries of (1, null) in the table, opposing to the unique key of (`id`, `second`).
"For multiple-row INSERT statements or INSERT INTO ... SELECT statements, the column is set to the implicit default value for the column data type. This is 0 for numeric types, the empty string ('') for string types, and the “zero” value for date and time types."
also appears to apply to a single row "replace into" query, which can be very confusing to debug when it appears to not obey the table constraints and just turns nulls/missing columns into empty strings. This can particularly be a problem if you have a unique constraint on one of those columns.
http://dev.mysql.com/doc/refman/5.1/en/string-literals.html