alter table test.demo_info modify column id int(7) not null auto\_increment comment 'ID';
alter table test.demo_info modify column name varchar(255) not null comment '姓名';
alter table test.demo_info modify column sex char(1) not null comment '性别:1-男,0-女';
alter table test.demo_info modify column age int(3) comment '年龄';
复制代码
一、命令source实现
2.1 导入数据
(1)准备insert.sql内容如下:
use test;
insert into test.demo_info(name,sex,age) values('张一','1',21);
insert into test.demo_info(name,sex,age) values('张二','0',22);
insert into test.demo_info(name,sex,age) values('张三','1',23);
复制代码
**存放路径:**C:/Users/Administrator/Desktop/insert.sql (2)先登录到MySQL命令行 打开cmd命令窗口,登录到MySQL命令行:
$ cd C:\Program Files\MySQL\MySQL Server 5.7\bin
$ mysql -hlocalhost -uroot -p --default-character-set=utf8 输入密码:
mysql > (3)执行source命令导入数据:
mysql> use test;
mysql> show tables;
mysql> select * from demo_info;
mysql> source C:/Users/Administrator/Desktop/insert.sql; 注意如果你数据库没有设置字符集为utf8,而且在连接时也没有指定--default-character-set=utf8连接,那么会导致插入中文数据时乱码,提示如下:
乱码原因是,默认客户端连接编码为GBK
mysql> use test;
mysql> show variables like '%character%';
select \* from test.demo_info into outfile 'C:/Users/Administrator/Desktop/demo\_info.txt';
复制代码
**select.sql存放路径:**C:/Users/Administrator/Desktop/select.sql (2)执行source命令导出数据:
mysql> source C:/Users/Administrator/Desktop/select.sql; 不过,别高兴太早,一般都会报错的,提示如下:
ERROR 1290 (HY000): The MySQL server is running with the –secure-file-priv option so it cannot execute this statement 原因是--secure-file-priv安全路径问题,具体往下进入到into outfile章节了解~
二、 into oufile和load data infile实现
2.1 into outfile
2.1.1 简单导出数据
导出数据通过into outfile语法实现,导入数据通过load data infile语法实现~ (1)条件条件说明 授权用户file权限:
mysql > select * from mysql.user where user='root' \G;
mysql > update mysql.user set File_priv='Y' where user='root';
mysql > select * from mysql.user where user='root' \G;
mysql > flush privileges; 如果没有授予用户的File_priv权限为Y,into outfile导出文件时会报错:
ERROR 1 (HY000): Can’t create/write to file ‘C:\Users\Administrator\Desktop\demo_info.txt’ (Errcode: 13 - Permission denied) 配置安全路径: MySQL使用into outfile语法导出数据时,只能导出数据文件到secure-file-priv指定的安全路径下~ 检察安全路径命令mysql> show variables like '%secure%';
如果指定导出文件路径不是安全路径下的,则会报错:
ERROR 1290 (HY000): The MySQL server is running with the –secure-file-priv option so it cannot execute this statement 简单导出测试下(非安全路径,如桌面):
select \* from test.demo_info into outfile 'C:/Users/Administrator/Desktop/demo\_info.txt';
复制代码
报错提示如下:
简单导出测试下(安全路径)
select \* from test.demo_info into outfile 'C:/ProgramData/MySQL/MySQL Server 5.7/Uploads/demo\_info.txt';
复制代码
正常导出demo_info.txt数据文件(注意Windows下路径不要用单反斜杠\)
(2)配置安全路径 如果不想用默认安全路径,可以修改参数--secure-file-priv为自界说路径,修改MySQL配置文件,一般默认的配置文件路径为:
Windows:C:\ProgramData\MySQL\MySQL Server 5.7\my.ini
Linux:/etc/my.cnf 安全路径在[mysqld]组下找到参数secure_file_priv举行配置即可~
select \* from demo_info into outfile 'C:/Users/Administrator/Desktop/demo\_info.del' character set utf8 fields terminated by 0x0f;
复制代码
导出的数据空间完全精密,不浪费任何空间,实际使用这种方式的非常多:
(2)终端命令行:
mysql -hlocalhost -uroot -p test -e "select \* from test.demo\_info into outfile 'C:/Users/Administrator/Desktop/demo\_info.del' character set utf8 fields terminated by 0x0f"
复制代码
into outfile参数说明:
参数说明character set utf8字符集utf8,防止中文乱码,必要放在fields前面,否则报错fields域,反面常用字段有terminated/optionally/escapedterminated by 'string'设置字段数据之间的分隔符,如最常用的分隔符0x0foptionally enclosed by 'char'设置字段非数值的数据,使用什么符号引起,如英文双引号"escaped by 'char'字段数据存在特殊符号使用的转移符,默认是反斜杠\,如还可以指定为双引号"lines设置每条记载的开头starting和末端字符terminatedlines starting by 'char'设置每条记载的开头字符,默认空字符串''lines terminated by 'char'设置每条记载的末端字符默认换行符'\n' 使用enclosed by参数示例:
select \* from demo_info into outfile 'C:/Users/Administrator/Desktop/demo\_info2.del' character set utf8 fields terminated by 0x0f optionally enclosed by '"';
复制代码
使用escaped by参数示例: 例如,把张三的名字反面加个特殊符号换行符\n
update test.demo_info set name='张一\n' where id=7;
复制代码
再执行导出命令:
select \* from test.demo_info into outfile 'C:/Users/Administrator/Desktop/demo\_info3.del' character set utf8 fields terminated by 0x0f optionally enclosed by '"' escaped by '"';
复制代码
使用lines参数示例:
update test.demo_info set name='张一' where id=7;
select \* from test.demo_info into outfile 'C:/Users/Administrator/Desktop/demo\_info4.del' character set utf8 fields terminated by 0x0f optionally enclosed by '"' escaped by '"' lines terminated by 'end\n' starting by 'start ';
load data infile 'C:/Users/Administrator/Desktop/demo\_info.txt' into table demo_info character set utf8;
复制代码
2.2.2 带格式导入数据
导入del数据文件(加载服务端文件): 命令行mysql>
load data infile 'C:/Users/Administrator/Desktop/demo\_info.del' into table demo_info character set utf8 fields terminated by 0x0f;
复制代码
load data infile参数说明:
参数说明character set utf8字符集utf8,防止中文乱码,必要放在fields前面,否则报错fields域,反面常用字段有terminated/optionally/escapedterminated by 'string'设置字段数据之间的分隔符,如最常用的分隔符0x0foptionally enclosed by 'char'设置字段非数值的数据,使用什么符号引起,如英文双引号"escaped by 'char'字段数据存在特殊符号使用的转移符,默认是反斜杠\,如还可以指定为双引号"lines设置每条记载的开头starting和末端字符terminatedlines starting by 'char'设置每条记载的开头字符,默认空字符串''lines terminated by 'char'设置每条记载的末端字符默认换行符'\n'(字段1,字段2,字段3)指定字段导入数据,注意放在整个语句最后,放前面,会报错 其实除了指定字段的参数,其他参数大多只必要跟into outfile导出参数一样,导出时有的参数,load data infile导入时该有的参数也加上就好~ 比如into outfile导出最复杂的情况如下(分隔符为0x0f、非数值双引号"扩起、特殊转义符使用双引号"转义、每条记载开头是start及末端是end\n)得到数据文件demo_info_complex_data.del
update test.demo_info set name='张一\n' where id=7;
select \* from test.demo_info into outfile 'C:/Users/Administrator/Desktop/demo\_info\_complex\_data.del' character set utf8 fields terminated by 0x0f optionally enclosed by '"' escaped by '"' lines terminated by 'end\n' starting by 'start ';
复制代码
可以看到demo_info_complex_data.del内容如下:
那么要导入demo_info_complex_data.del对应的load data infile语法完整SQL语句为:
load data infile 'C:/Users/Administrator/Desktop/demo\_info\_complex\_data.del' into table demo_info character set utf8 fields terminated by 0x0f optionally enclosed by '"' escaped by '"' lines terminated by 'end\n' starting by 'start ';
复制代码
其实很简单,把into outfile导出数据时character反面的参数直接copy过来就行~
Linux终端命令:
mkdir -p /batchfile/mysql/data/test/
mysql -hlocalhost -uroot -p test -e "load data infile '/batchfile/mysql/data/test/demo\_info.del' into table demo\_info character set utf8 fields terminated by 0x0f"
复制代码
导入del数据文件(加载客户端本地LOCAL文件): 命令行mysql>
load data LOCAL infile 'C:/Users/Administrator/Desktop/demo\_info.del' into table demo_info character set utf8 fields terminated by 0x0f;
复制代码
Linux终端命令:
mysql -hlocalhost -uroot -p test -e "load data LOCAL infile '/batchfile/mysql/data/test/demo\_info.del' into table demo\_info character set utf8 fields terminated by 0x0f"
复制代码
注意:如果MySQL服务端在Linux,load data infile默认是加载服务端路径的数据文件,指定LOCAL体现加载的是客户端的本地数据文件~
三、工具mysqldump实现