The mysqlimport client provides a
command-line interface to the
LOAD DATA
INFILE
SQL statement. Most options to
mysqlimport correspond directly to clauses of
LOAD DATA
INFILE
syntax. See Section 12.2.6, “LOAD DATA INFILE
Syntax”.
Invoke mysqlimport like this:
shell> mysqlimport [options
] db_name
textfile1
[textfile2
...]
For each text file named on the command line,
mysqlimport strips any extension from the
file name and uses the result to determine the name of the table
into which to import the file's contents. For example, files
named patient.txt
,
patient.text
, and
patient
all would be imported into a table
named patient
.
mysqldump supports the following options,
which can be specified on the command line or in the
[mysqldump]
and [client]
option file groups. mysqldump also supports
the options for processing option files described at
Section 4.2.3.3.1, “Command-Line Options that Affect Option-File Handling”.
Table 4.6. mysqlimport
Options
Format | Config File | Description | Introduction | Deprecated | Removed |
---|---|---|---|---|---|
--columns=column_list | columns | This option takes a comma-separated list of column names as its value | |||
--compress | compress | Compress all information sent between the client and the server | |||
--debug[=debug_options] | debug | Write a debugging log | |||
--default-character-set=charset_name | default-character-set | Use charset_name as the default character set | |||
--delete | delete | Empty the table before importing the text file | |||
--fields-enclosed-by=string | fields-enclosed-by | This option has the same meaning as the corresponding clause for LOAD DATA INFILE | |||
--fields-escaped-by | fields-escaped-by | This option has the same meaning as the corresponding clause for LOAD DATA INFILE | |||
--fields-optionally-enclosed-by=string | fields-optionally-enclosed-by | This option has the same meaning as the corresponding clause for LOAD DATA INFILE | |||
--fields-terminated-by=string | fields-terminated-by | -- This option has the same meaning as the corresponding clause for LOAD DATA INFILE | |||
--force | force | Continue even if an SQL error occurs | |||
--help | Display help message and exit | ||||
--host=host_name | host | Connect to the MySQL server on the given host | |||
--ignore | ignore | See the description for the --replace option | |||
--ignore-lines=# | ignore-lines | Ignore the first N lines of the data file | |||
--lines-terminated-by=string | lines-terminated-by | This option has the same meaning as the corresponding clause for LOAD DATA INFILE | |||
--local | local | Read input files locally from the client host | |||
--lock-tables | lock-tables | Lock all tables for writing before processing any text files | |||
--low-priority | low-priority | Use LOW_PRIORITY when loading the table. | |||
--password[=password] | password | The password to use when connecting to the server | |||
--pipe | On Windows, connect to server via a named pipe | ||||
--port=port_num | port | The TCP/IP port number to use for the connection | |||
--protocol=type | protocol | The connection protocol to use | |||
--replace | replace | The --replace and --ignore options control handling of input rows that duplicate existing rows on unique key values | |||
--silent | silent | Produce output only when errors occur | |||
--socket=path | socket | For connections to localhost | |||
--ssl-ca=file_name | ssl-ca | The path to a file that contains a list of trusted SSL CAs | |||
--ssl-capath=directory_name | ssl-capath | The path to a directory that contains trusted SSL CA certificates in PEM format | |||
--ssl-cert=file_name | ssl-cert | The name of the SSL certificate file to use for establishing a secure connection | |||
--ssl-cipher=cipher_list | ssl-cipher | A list of allowable ciphers to use for SSL encryption | |||
--ssl-key=file_name | ssl-key | The name of the SSL key file to use for establishing a secure connection | |||
--ssl-verify-server-cert | ssl-verify-server-cert | The server's Common Name value in its certificate is verified against the host name used when connecting to the server | |||
--user=user_name, | user | The MySQL user name to use when connecting to the server | |||
--verbose | Verbose mode | ||||
--version | Display version information and exit |
--help
,
-?
Display a help message and exit.
The directory where character sets are installed. See Section 9.5, “Character Set Configuration”.
--columns=
,
column_list
-c
column_list
This option takes a comma-separated list of column names as its value. The order of the column names indicates how to match data file columns with table columns.
--compress
,
-C
Compress all information sent between the client and the server if both support compression.
--debug[=
,
debug_options
]-#
[
debug_options
]
Write a debugging log. A typical
debug_options
string is
'd:t:o,
.
The default is file_name
''d:t:o'
.
--default-character-set=
charset_name
Use charset_name
as the default
character set. See Section 9.5, “Character Set Configuration”.
--delete
,
-D
Empty the table before importing the text file.
--fields-terminated-by=...
,
--fields-enclosed-by=...
,
--fields-optionally-enclosed-by=...
,
--fields-escaped-by=...
These options have the same meaning as the corresponding
clauses for LOAD
DATA INFILE
. See Section 12.2.6, “LOAD DATA INFILE
Syntax”.
--force
,
-f
Ignore errors. For example, if a table for a text file does
not exist, continue processing any remaining files. Without
--force
,
mysqlimport exits if a table does not
exist.
--host=
,
host_name
-h
host_name
Import data to the MySQL server on the given host. The
default host is localhost
.
--ignore
,
-i
See the description for the
--replace
option.
Ignore the first N
lines of the
data file.
This option has the same meaning as the corresponding clause
for LOAD DATA
INFILE
. For example, to import Windows files that
have lines terminated with carriage return/linefeed pairs,
use
--lines-terminated-by="\r\n"
.
(You might have to double the backslashes, depending on the
escaping conventions of your command interpreter.) See
Section 12.2.6, “LOAD DATA INFILE
Syntax”.
--local
,
-L
Read input files locally from the client host.
MySQL Enterprise.
For expert advice on the security implications of enabling
LOCAL
, subscribe to the MySQL
Enterprise Monitor. For more information, see
http://www.mysql.com/products/enterprise/advisors.html.
--lock-tables
,
-l
Lock all tables for writing before processing any text files. This ensures that all tables are synchronized on the server.
Use LOW_PRIORITY
when loading the table.
This affects only storage engines that use only table-level
locking (such as MyISAM
,
MEMORY
, and MERGE
).
--password[=
,
password
]-p[
password
]
The password to use when connecting to the server. If you
use the short option form (-p
), you
cannot have a space between the option
and the password. If you omit the
password
value following the
--password
or
-p
option on the command line,
mysqlimport prompts for one.
Specifying a password on the command line should be considered insecure. See Section 5.3.2.2, “End-User Guidelines for Password Security”. You can use an option file to avoid giving the password on the command line.
--pipe
,
-W
On Windows, connect to the server via a named pipe. This option applies only if the server supports named-pipe connections.
--port=
,
port_num
-P
port_num
The TCP/IP port number to use for the connection.
--protocol={TCP|SOCKET|PIPE|MEMORY}
The connection protocol to use for connecting to the server. It is useful when the other connection parameters normally would cause a protocol to be used other than the one you want. For details on the allowable values, see Section 4.2.2, “Connecting to the MySQL Server”.
--replace
,
-r
The --replace
and
--ignore
options control
handling of input rows that duplicate existing rows on
unique key values. If you specify
--replace
, new rows
replace existing rows that have the same unique key value.
If you specify --ignore
,
input rows that duplicate an existing row on a unique key
value are skipped. If you do not specify either option, an
error occurs when a duplicate key value is found, and the
rest of the text file is ignored.
--silent
,
-s
Silent mode. Produce output only when errors occur.
--socket=
,
path
-S
path
For connections to localhost
, the Unix
socket file to use, or, on Windows, the name of the named
pipe to use.
Options that begin with
--ssl
specify whether to
connect to the server via SSL and indicate where to find SSL
keys and certificates. See Section 5.5.6.3, “SSL Command Options”.
--user=
,
user_name
-u
user_name
The MySQL user name to use when connecting to the server.
--verbose
,
-v
Verbose mode. Print more information about what the program does.
--version
,
-V
Display version information and exit.
Here is a sample session that demonstrates use of mysqlimport:
shell>mysql -e 'CREATE TABLE imptest(id INT, n VARCHAR(30))' test
shell>ed
a 100 Max Sydow 101 Count Dracula . w imptest.txt 32 q shell>od -c imptest.txt
0000000 1 0 0 \t M a x S y d o w \n 1 0 0000020 1 \t C o u n t D r a c u l a \n 0000040 shell>mysqlimport --local test imptest.txt
test.imptest: Records: 2 Deleted: 0 Skipped: 0 Warnings: 0 shell>mysql -e 'SELECT * FROM imptest' test
+------+---------------+ | id | n | +------+---------------+ | 100 | Max Sydow | | 101 | Count Dracula | +------+---------------+
User Comments
Keep in mind that your imported text file should
have some value for empty fields. I regularly
build tables using msqlimport to import
tab-delimited text files. My tables contain
integer fields, some of which are
auto_incremented and some are not. MYSQL will
let you represent empty fields as null text
strings, i.e., two tab characters back-to-back,
but I found this increments the warning count.
To solve this problem you must use some value
for empty fields. Since auto_increment fields
use 0 or NULL, one would think, incorrectly,
that you could use 0 or \N to represent a null
value in the import text file. You must 0 for
an auto_increment field. Using \N increments
the warning count. You should use \N for other
numeric fields where you want a null value.
This problem is especially perplexing because of
MySQL's inability to report the text of a
warning. It only reports a warning count.
Before you invoke mysqlimport command with
appropriate options, please check that the 'FILE'
privilege is granted to you.
I wasted time facing the 'Access Denied on
table_name' error
because of the same.
Mysqlimport - access_to_mysql.txt - Usage - reg.
While converting the data from Microsoft Access database to Mysql, I have used the access_to_mysql.txt tool. In my database, some of the tables were were linked with another microsoft access database for which password has been set. Hence while converting the data, it displayed an error.
To over come this, I opened the database which has the linked table and removed the password set for that database.
Once password is removed, all the tables and data was successfully transferred to C:\temp\mysqldump.txt file.
If you get an "access denied" error message,
you may want to try the --local option to mysqlimport.
If your mysqlimport's are not working anymore after the upgrade to mysql 4.0.22, try adding this to your my.cnf:
[mysqlimport]
local = 1
Or add "--local" to your scripts...
If you are one of the many people trying to import a CSV file into MySQL using mysqlimport under MS-Windows command/DOS prompt, try the following:
mysqlimport --fields-optionally-enclosed-by=""" --fields-terminated-by=, --lines-terminated-by="\r\n" --user=YOUR_USERNAME --password YOUR_DATABASE YOUR_TABLE.csv
Between quotes " and backslashes \ it can really give you a hard time finding the proper combination under Windows...
I usually run this command from the folder containing the YOUR_TABLE.csv file.
If you have a header in your .csv file with the name of columns or other "junk" in it, just add a --ignore-lines=X to skip the first X lines (i.e. --ignore-lines=1 to skip 1 line)
If your fields are (optionally) enclosed by double-quotes " and which themselves are doubled inside a value (i.e. a double double-quote "" = 1 double-quote ") then also use --fields-escaped-by=\ (default) and NOT --fields-escaped-by="""
I hope this helps someone,
-Philippe
If your use the --delete or -D commands AND you are importing multiple files to the same database, the screen messages indicate it clears the table before each import file. If this is true, you will only ever have the data from the last imported file.
If you want to skip columns from the import file
try using something like --columns=col1,@x,col2
This will skip the second column, sending it to
the variable @x instead of the destination table.
I was getting a 'field too long' error, but using the --columns flag as below worked for me on Windows.
(for localhost import)
mysqlimport --fields-terminated-by=, --lines-terminated-by="\r\n" DBNAME FILENAME -u USERNAME -p --delete --columns=code,city,state,county
-Luke
http://lukewendling.com
I found I had to use the **complete path** to the table file - rather than using "./mytable.txt":
./bin/mysqlimport --columns=title,body --fields-terminated-by="||" kb /usr/local/mysql/s_kb_entry.txt
Otherwise mysqlimport went looking for the table.txt file in the data directory.
This works fine importing csv file to table called tbl_temp_data
import large csv file in to mysql
LOAD DATA LOCAL INFILE C:\test.csv
INTO TABLE tbl_temp_data
FIELDS TERMINATED BY ','
LINES TERMINATED BY '\r\n'
If your csv file is less than 1MB and with default mysql configuration this works good, but
if you have csv file size larger than 1MB then it will not import that file.you have to change max packet size varible value (default is 1Mb)
using mysql-administrator GUI you can easily change this
value
In mysql-administrator GUI --> startup varables --> Advanced Networking tab --> data/memory size group box --> Max packet size = ""
.................. have fun with mysql .........
When I used mysqlimport I found both DOS and Linux were just bombing out with showing me the usage blurb again without any reason. I finally figured out that
--fields-optionally-enclosed-by="""
is incorrect, you need to escape the middle " as shown in this full example:
mysqlimport --fields-optionally-enclosed-by="\"" --fields-terminated-by=, --lines-terminated-by="\r\n" --user=YOUR_USERNAME --password YOUR_DATABASE YOUR_TABLE.csv
the above example also assumes you have copied your YOUR_TABLE.csv file into the data directory for YOUR_DATABASE, though I think I read you can specify an absolute path to YOUR_TABLE.csv also.
The --local option is VERY important if you want to import a file from anywhere else other than /var/lib/mysql/table_name directory. If you use --local then you can use the FULL path to the file that you want to import and you do not have to make any changes to the directory permissions for the /var/lib/mysql directory to move files around. It took me a little while to understand what this option meant.
I thought I would share this as it was very frustrating.
Add your own comment.