I am stuck in a situation where I have to read data from 3 separate large CSV files and store it in MySQL database.
csv file columns:
total_rev,monthly_rev,day_rev
Database table's columns:
total_rev, monthly_rev, day_rev, from
I am able to insert data in my table by using following query:
LOAD DATA LOCAL INFILE '/home/datauser/Desktop/working/revenue_2016_10_06.csv'
INTO TABLE revenue_table
FIELDS TERMINATED BY ','
LINES TERMINATED BY '\n'
(total_rev,monthly_rev,day_rev);
But I am stuck in a situation where I want to add hard coded parameter in the "Load Data Local" query to add from's value depending upon the file.
so at the end my table will contain records like:
total_rev, monthly_rev, day_rev, from
11, 222, 333, file1
22, 32, 343, file1
11, 22, 333, file1
11, 22, 33, file22
11, 22, 33, file22
How can I specify this file1, file22 value's in above query ?
Add a SET
clause to the LOAD DATA statement, to assign a value to the (unfortunately named) from
column:
LOAD DATA LOCAL INFILE '/home/datauser/Desktop/working/revenue_2016_10_06.csv'
INTO TABLE revenue_table
FIELDS TERMINATED BY ','
LINES TERMINATED BY '\n'
(total_rev,monthly_rev,day_rev)
SET `from` = 'file1'
;
Note that it's also possible to load the fields from the file into user-defined variables and/or reference user-defined variables in the SET clause.
SET @file_name = 'myfilename'
;
LOAD DATA LOCAL INFILE '/home/datauser/Desktop/working/revenue_2016_10_06.csv'
INTO TABLE revenue_table
FIELDS TERMINATED BY ','
LINES TERMINATED BY '\n'
( @total_rev
, @monthly_rev
, @day_rev
)
SET `total_rev` = @total_rev
, `monthly_rev` = @monthly_rev
, `day_rev` = @day_rev
, `from` = @file_name
;
If we had fields in the file we want to skip, not load into the table, we can use a user-defined variable as a placeholder. We can also use expressions in the SET clause, which allows us to leverage some very useful MySQL functions for some manipulation... IFNULL, NULLIF, STR_TO_DATE, CONCAT, etc.