MySQL 之 LOAD DATA INFILE 快速导入数据 (单表数据很大)
SELECT INTO OUTFILE
> help select; Name: ‘SELECT‘ Description: Syntax: SELECT [ALL | DISTINCT | DISTINCTROW ] [HIGH_PRIORITY] [MAX_STATEMENT_TIME = N] [STRAIGHT_JOIN] [SQL_SMALL_RESULT] [SQL_BIG_RESULT] [SQL_BUFFER_RESULT] [SQL_CACHE | SQL_NO_CACHE] [SQL_CALC_FOUND_ROWS] select_expr [, select_expr ...] [FROM table_references [PARTITION partition_list] [WHERE where_condition] [GROUP BY {col_name | expr | position} [ASC | DESC], ... [WITH ROLLUP]] [HAVING where_condition] [ORDER BY {col_name | expr | position} [ASC | DESC], ...] [LIMIT {[offset,] row_count | row_count OFFSET offset}] [PROCEDURE procedure_name(argument_list)] [INTO OUTFILE ‘file_name‘ [CHARACTER SET charset_name] export_options | INTO DUMPFILE ‘file_name‘ | INTO var_name [, var_name]] [FOR UPDATE | LOCK IN SHARE MODE]]
举例:
> select * from e; +------+-------+-------+ | id | fname | lname | +------+-------+-------+ | 1669 | Jim | Smith | | 337 | Mary | Jones | | 2005 | Linda | Black | +------+-------+-------+ > select * from e into outfile "/data/mysql/e.sql";或 > select * into outfile "/data/mysql/e.sql" from e; # cat e.sql 1669 Jim Smith 337 Mary Jones 2005 Linda Black
可以看到,select...into outfile 的结果只包含了表数据,默认以 Tab 分隔,也可指定分隔符:
> select * from e into outfile "/data/mysql/e.sql" fields terminated by ‘,‘; # cat e.sql 1669,Jim,Smith 337,Mary,Jones 2005,Linda,Black
注意:outfile ‘/path/file‘,中的 path 需要有mysql的权限,否则会报错:
> select * from t into outfile "/root/backup/mysql/t.sql"; ERROR 1 (HY000): Can‘t create/write to file ‘/root/backup/mysql/t.sql‘ (Errcode: 13 - Permission denied)
LOAD DATA INFILE
LOAD DATA INFILE 语句以非常高的速度从文本文件中读取行到表中。
LOAD DATA [LOW_PRIORITY | CONCURRENT] [LOCAL] INFILE ‘file_name‘ [REPLACE | IGNORE] INTO TABLE tbl_name [PARTITION (partition_name,...)] [CHARACTER SET charset_name] [{FIELDS | COLUMNS} [TERMINATED BY ‘string‘] [[OPTIONALLY] ENCLOSED BY ‘char‘] [ESCAPED BY ‘char‘] ] [LINES [STARTING BY ‘string‘] [TERMINATED BY ‘string‘] ] [IGNORE number {LINES | ROWS}] [(col_name_or_user_var,...)] [SET col_name = expr,...]
注意:load data 需要有处理文件的权限, GRANT FILE ON *.* TO ;
举例:
> delete from e;> load data infile "/data/mysql/e.sql" into table e fields terminated by ‘,‘; Query OK, 3 rows affected (0.01 sec) Records: 3 Deleted: 0 Skipped: 0 Warnings: 0 > select * from e; +------+-------+-------+ | id | fname | lname | +------+-------+-------+ | 1669 | Jim | Smith | | 337 | Mary | Jones | | 2005 | Linda | Black | +------+-------+-------+
因为我们前面指定的分隔符是 ‘,‘,load data 时也要指定分隔符,否则也会报错:
> load data infile "/data/mysql/e.sql" into table e; ERROR 1265 (01000): Data truncated for column ‘id‘ at row 1
如果数据被某种符号封闭着,需要指定 ‘ fields enclosed by ’ :
# cat e.sql "1669" "Jim" "Smith"
> load data infile "/data/mysql/e.sql" into table e;
ERROR 1366 (HY000): Incorrect integer value: ‘"1669"‘ for column ‘id‘ at row 1
> load data infile "/data/mysql/e.sql" into table e fields enclosed by ‘"‘;
Query OK, 1 row affected (0.01 sec)
Records: 1 Deleted: 0 Skipped: 0 Warnings: 0
如上所示,数据被双引号封闭着,如果直接执行,会报错。
另外还有一些格式上的限制,如 LINES TERMINATED BY ‘string‘ ,指定 file 的换行符,如 ‘\n’ 。
load data 还有很多种用法
- LOAD DATA INFILE ... [REPLACE|IGNORE] INTO TABLE : replace into 表示如果导入过程中有唯一性约束,直接覆盖;ignore into 则跳过。
- LOAD DATA LOCAL INFILE : 在非服务端执行load data需要使用local。比如在 ipA 处登录 ipB 上的mysqld,就需要用到 local 。
- 可以指定字段: LOAD DATA INFILE ... INTO TABLE xxx (col1,col2,...)
- 可以设定值: LOAD DATA LOCAL INFILE ‘$tmpfile‘ REPLACE INTO TABLE db.tbname (a,b,c,d,e,f) set g=11,h=‘xxx‘;
注意:执行 select into outfile 和 load data infile 需要开启 secure_file_priv ,空值代表文件可以在任意处,也可指定具体路径,NULL表示禁止使用。
mysqlimport
mysql 命令中有 load data ,mysql还有一个可执行文件 mysqlimport,这两个命令可以从文件中把格式化的数据导入数据库,如果有一个包含大数据量的文件,可以实现快速的数据导入。
mysqlimport 可以看做是为 LOAD DATA INFILE SQL语句提供了一个命令行界面,他们大部分的参数选项是一致的,由 SELECT into outfile 导出的文件,也可以由 mysqlimport 导入。
mysqlimport 需要的文件格式与 load data 差不多,有兴趣的同学可以去研究一下。这里给出它的基本语法:
mysqlimport -u root -pPassword [--local] dbname filename.txt [OPTION]
其中,“Password”参数是root用户的密码,必须与-p选项紧挨着;“--local”是在本地计算机中查找文本文件时使用的(指定 --local 后,文本文件可以放在任何地方进行导入,否则只能放在mysql的data目录下);“dbname”参数表示数据库的名称;“filename.txt”参数指定了文本文件的路径和称,文件里的数据插入到文件名去掉后缀后剩余名字对应的表中;“OPTION”为可选参数选项,其常见的取值有:
--fields-terminated-by=字符串:设置字符串为字段之间的分隔符,可以为单个或多个字符。默认值为制表符“\t”。
--fields-enclosed-by=字符:设置字符来括住字段的值,只能为单个字符。
--fields-optionally-enclosed-by=字符:设置字符括住CHAR、VARCHAR和TEXT等字符型字段,只能为单个字符。
--fields-escaped-by=字符:设置转义字符,默认值为反斜线“\”。
--lines-terminated-by=字符串:设置每行数据结尾的字符,可以为单个或多个字符,默认值为“\n”。
--ignore-lines=n:表示可以忽略前n行。