OBSERVATION #1
You should not do REPLACE
because it is a mechanical DELETE
and INSERT
.
As the MySQL Documentation says about REPLACE
Paragraph 2
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 13.2.5.3, “INSERT ... ON DUPLICATE KEY UPDATE Syntax”.
Paragraph 5
To use REPLACE, you must have both the INSERT and DELETE privileges for the table.
Using REPLACE will throw away established values for TEST_ID that cannot automatically be reused.
OBSERVATION #2
The table layout will not support trapping of duplicate keys
If a name is unique, the table should be laid out like this
LAYOUT #1
CREATE TABLE `oxygen_domain`.`TEST` (
`TEST_ID` int(11) NOT NULL AUTO_INCREMENT,
`NAME` varchar(255) NOT NULL,
`VALUE` varchar(255) DEFAULT NULL,
PRIMARY KEY (`TEST_ID`),
KEY (`NAME`)
)
If a name allows multiple values, the table should be laid out like this
LAYOUT #2
CREATE TABLE `oxygen_domain`.`TEST` (
`TEST_ID` int(11) NOT NULL AUTO_INCREMENT,
`NAME` varchar(255) NOT NULL,
`VALUE` varchar(255) DEFAULT NULL,
PRIMARY KEY (`TEST_ID`),
KEY (`NAME`,`VALUE`)
)
PROPOSED SOLUTION
Use a temp table to catch everything. Then, perform a big INSERT from the temp table based on layout
LAYOUT #1
Replace the VALUE
for a Duplicate NAME
USE oxygen_domain
DROP TABLE IF EXISTS `TESTLOAD`;
CREATE TABLE `TESTLOAD` SELECT NAME,VALUE FROM TEST WHERE 1=2;
LOAD DATA LOCAL INFILE 'C:/testData.txt'
INTO TABLE `TESTLOAD`
FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"'
LINES TERMINATED BY '\r\n'
IGNORE 1 LINES
(NAME, VALUE);
INSERT INTO `TEST` (NAME, VALUE)
SELECT NAME, VALUE FROM `TESTLOAD`
ON DUPLICATE KEY UPDATE VALUE = VALUES(VALUE);
DROP TABLE `TESTLOAD`;
LAYOUT #2
Ignore Duplicate (NAME,VALUE)
rows
USE oxygen_domain
DROP TABLE IF EXISTS `TESTLOAD`;
CREATE TABLE `TESTLOAD` SELECT NAME,VALUE FROM TEST WHERE 1=2;
LOAD DATA LOCAL INFILE 'C:/testData.txt'
INTO TABLE `TESTLOAD`
FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY '"'
LINES TERMINATED BY '\r\n'
IGNORE 1 LINES
(NAME, VALUE);
INSERT IGNORE INTO `TEST` (NAME, VALUE)
SELECT NAME, VALUE FROM `TESTLOAD`;
DROP TABLE `TESTLOAD`;
Update
if we need to avoid the creating and dropping of the table each time. we can TRUNCATE TRUNCATE the table before or after using INSERT...INTO statement. Therefore, we do not have to create the table next time.