暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

MySQL表相关操作小结

原创 只是甲 2020-07-29
1008

备注:测试数据库版本为MySQL 8.0

这个blog我们来聊聊MySQL 表相关操作

Table of Contents

一.创建表

语法:

CREATE [TEMPORARY] TABLE [IF NOT EXISTS] tbl_name (create_definition,...) [table_options] [partition_options] CREATE [TEMPORARY] TABLE [IF NOT EXISTS] tbl_name [(create_definition,...)] [table_options] [partition_options] [IGNORE | REPLACE] [AS] query_expression CREATE [TEMPORARY] TABLE [IF NOT EXISTS] tbl_name { LIKE old_tbl_name | (LIKE old_tbl_name) } create_definition: { col_name column_definition | {INDEX | KEY} [index_name] [index_type] (key_part,...) [index_option] ... | {FULLTEXT | SPATIAL} [INDEX | KEY] [index_name] (key_part,...) [index_option] ... | [CONSTRAINT [symbol]] PRIMARY KEY [index_type] (key_part,...) [index_option] ... | [CONSTRAINT [symbol]] UNIQUE [INDEX | KEY] [index_name] [index_type] (key_part,...) [index_option] ... | [CONSTRAINT [symbol]] FOREIGN KEY [index_name] (col_name,...) reference_definition | check_constraint_definition } column_definition: { data_type [NOT NULL | NULL] [DEFAULT {literal | (expr)} ] [AUTO_INCREMENT] [UNIQUE [KEY]] [[PRIMARY] KEY] [COMMENT 'string'] [COLLATE collation_name] [COLUMN_FORMAT {FIXED | DYNAMIC | DEFAULT}] [STORAGE {DISK | MEMORY}] [reference_definition] [check_constraint_definition] | data_type [COLLATE collation_name] [GENERATED ALWAYS] AS (expr) [VIRTUAL | STORED] [NOT NULL | NULL] [UNIQUE [KEY]] [[PRIMARY] KEY] [COMMENT 'string'] [reference_definition] [check_constraint_definition] } data_type: (see Chapter 11, Data Types) key_part: {col_name [(length)] | (expr)} [ASC | DESC] index_type: USING {BTREE | HASH} index_option: { KEY_BLOCK_SIZE [=] value | index_type | WITH PARSER parser_name | COMMENT 'string' | {VISIBLE | INVISIBLE} } check_constraint_definition: [CONSTRAINT [symbol]] CHECK (expr) [[NOT] ENFORCED] reference_definition: REFERENCES tbl_name (key_part,...) [MATCH FULL | MATCH PARTIAL | MATCH SIMPLE] [ON DELETE reference_option] [ON UPDATE reference_option] reference_option: RESTRICT | CASCADE | SET NULL | NO ACTION | SET DEFAULT table_options: table_option [[,] table_option] ... table_option: { AUTO_INCREMENT [=] value | AVG_ROW_LENGTH [=] value | [DEFAULT] CHARACTER SET [=] charset_name | CHECKSUM [=] {0 | 1} | [DEFAULT] COLLATE [=] collation_name | COMMENT [=] 'string' | COMPRESSION [=] {'ZLIB' | 'LZ4' | 'NONE'} | CONNECTION [=] 'connect_string' | {DATA | INDEX} DIRECTORY [=] 'absolute path to directory' | DELAY_KEY_WRITE [=] {0 | 1} | ENCRYPTION [=] {'Y' | 'N'} | ENGINE [=] engine_name | INSERT_METHOD [=] { NO | FIRST | LAST } | KEY_BLOCK_SIZE [=] value | MAX_ROWS [=] value | MIN_ROWS [=] value | PACK_KEYS [=] {0 | 1 | DEFAULT} | PASSWORD [=] 'string' | ROW_FORMAT [=] {DEFAULT | DYNAMIC | FIXED | COMPRESSED | REDUNDANT | COMPACT} | STATS_AUTO_RECALC [=] {DEFAULT | 0 | 1} | STATS_PERSISTENT [=] {DEFAULT | 0 | 1} | STATS_SAMPLE_PAGES [=] value | TABLESPACE tablespace_name [STORAGE {DISK | MEMORY}] | UNION [=] (tbl_name[,tbl_name]...) } partition_options: PARTITION BY { [LINEAR] HASH(expr) | [LINEAR] KEY [ALGORITHM={1 | 2}] (column_list) | RANGE{(expr) | COLUMNS(column_list)} | LIST{(expr) | COLUMNS(column_list)} } [PARTITIONS num] [SUBPARTITION BY { [LINEAR] HASH(expr) | [LINEAR] KEY [ALGORITHM={1 | 2}] (column_list) } [SUBPARTITIONS num] ] [(partition_definition [, partition_definition] ...)] partition_definition: PARTITION partition_name [VALUES {LESS THAN {(expr | value_list) | MAXVALUE} | IN (value_list)}] [[STORAGE] ENGINE [=] engine_name] [COMMENT [=] 'string' ] [DATA DIRECTORY [=] 'data_dir'] [INDEX DIRECTORY [=] 'index_dir'] [MAX_ROWS [=] max_number_of_rows] [MIN_ROWS [=] min_number_of_rows] [TABLESPACE [=] tablespace_name] [(subpartition_definition [, subpartition_definition] ...)] subpartition_definition: SUBPARTITION logical_name [[STORAGE] ENGINE [=] engine_name] [COMMENT [=] 'string' ] [DATA DIRECTORY [=] 'data_dir'] [INDEX DIRECTORY [=] 'index_dir'] [MAX_ROWS [=] max_number_of_rows] [MIN_ROWS [=] min_number_of_rows] [TABLESPACE [=] tablespace_name] query_expression: SELECT ... (Some valid select or union statement)
复制

MySQL的建表语句的语法太长了,看起来都觉得好麻烦
下面将建表的语法分解开

1.1 Table Name

类型 描述
Table Name 创建的表名称
举例:
1.tbl_name
2.db_name.tbl_name
3.’mydb'.’mytbl'
IF NOT EXISTS 如表名已存在 不报错
-- 用三种不同的表名的格式来创建表 create table t1(id int,name varchar(100)); create table test1.t2(id int,name varchar(100)); create table `test1`.`t3`(id int,name varchar(100)); -- 创建同名的表 if not exists未报错 有警告 且表为进行覆盖,依旧是原来的表 create table t1(id int,name varchar(100)); create table if not exists t1(id int,name varchar(100),type varchar(100)); show warnings\G show create table t1\G
复制

执行记录:

mysql> drop table t1,t2,t3; Query OK, 0 rows affected (0.03 sec) mysql> mysql> mysql> -- 用三种不同的表名的格式来创建表 mysql> create table t1(id int,name varchar(100)); Query OK, 0 rows affected (0.02 sec) mysql> create table test1.t2(id int,name varchar(100)); Query OK, 0 rows affected (0.02 sec) mysql> create table `test1`.`t3`(id int,name varchar(100)); Query OK, 0 rows affected (0.02 sec) mysql> -- 创建同名的表 if not exists未报错 有警告 且表为进行覆盖,依旧是原来的表 mysql> create table t1(id int,name varchar(100)); ERROR 1050 (42S01): Table 't1' already exists mysql> create table if not exists t1(id int,name varchar(100),type varchar(100)); Query OK, 0 rows affected, 1 warning (0.00 sec) mysql> show warnings\G *************************** 1. row *************************** Level: Note Code: 1050 Message: Table 't1' already exists 1 row in set (0.00 sec) mysql> show create table t1\G *************************** 1. row *************************** Table: t1 Create Table: CREATE TABLE `t1` ( `id` int DEFAULT NULL, `name` varchar(100) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec)
复制

1.2 Temporary Tables

MySQL的临时表与Oracle的全局临时表存在一定的差异
MySQL的临时表仅限当前的session有效,其它session即看不到表也看不到数据
InnoDB存储引擎不支持压缩的临时表
innodb_file_per-table 对临时表不会生效 临时表默认存储在 #innodb_temp 目录

-- session A:创建临时表 CREATE TEMPORARY TABLE new_tbl SELECT * FROM orig_tbl LIMIT 0; show create table tmp_1\G insert into tmp_1 (id,name) values (1,'abc'); select * from tmp_1; -- session B: 查询临时表 提示表不存在 select * from tmp_1;
复制

执行记录:

-- Session A: mysql> create temporary table tmp_1(id int,name varchar(100)); Query OK, 0 rows affected (0.01 sec) mysql> show create table tmp_1\G *************************** 1. row *************************** Table: tmp_1 Create Table: CREATE TEMPORARY TABLE `tmp_1` ( `id` int DEFAULT NULL, `name` varchar(100) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql> insert into tmp_1 (id,name) values (1,'abc'); Query OK, 1 row affected (0.01 sec) mysql> select * from tmp_1; +------+------+ | id | name | +------+------+ | 1 | abc | +------+------+ 1 row in set (0.00 sec) -- Session B: mysql> use test1; Database changed mysql> mysql> select * from tmp_1; ERROR 1146 (42S02): Table 'test1.tmp_1' doesn't exist
复制

1.3 Table Cloning and Copying

表的克隆和拷贝

-- 建表,不拷贝数据 表结构和约束都会同时拷贝 CREATE TABLE new_tbl LIKE orig_tbl; -- 建表,同时拷贝数据 表结构和数据会拷贝 表约束不会拷贝 CREATE TABLE new_tbl AS SELECT * FROM orig_tbl;
复制
create table test1 (id int auto_increment primary key,name varchar(100)); insert into test1(name) values ('abc'); select * from test1; show create table test1; -- like拷贝表定义 create table t_like like test1; select * from t_like; show create table t_like; -- ctas 拷贝数据,主键约束没有过来 create table t_ctas as select * from test1; select * from test1; show create table t_ctas;
复制

执行记录:

mysql> create table test1 (id int auto_increment primary key,name varchar(100)); Query OK, 0 rows affected (0.03 sec) mysql> insert into test1(name) values ('abc'); Query OK, 1 row affected (0.01 sec) mysql> mysql> select * from test1; +----+------+ | id | name | +----+------+ | 1 | abc | +----+------+ 1 row in set (0.00 sec) mysql> mysql> show create table test1; +-------+------------------------------------------------------------------------------------------------------------------------------------------------------- --------------------+ | Table | Create Table | +-------+------------------------------------------------------------------------------------------------------------------------------------------------------- --------------------+ | test1 | CREATE TABLE `test1` ( `id` int NOT NULL AUTO_INCREMENT, `name` varchar(100) DEFAULT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB AUTO_INCREMENT=2 DEFAULT CHARSET=utf8 | +-------+------------------------------------------------------------------------------------------------------------------------------------------------------- --------------------+ 1 row in set (0.01 sec) mysql> mysql> mysql> mysql> create table t_like like test1; Query OK, 0 rows affected (0.03 sec) mysql> select * from t_like; Empty set (0.01 sec) mysql> show create table t_like; +--------+------------------------------------------------------------------------------------------------------------------------------------------------------ -----+ | Table | Create Table | +--------+------------------------------------------------------------------------------------------------------------------------------------------------------ -----+ | t_like | CREATE TABLE `t_like` ( `id` int NOT NULL AUTO_INCREMENT, `name` varchar(100) DEFAULT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 | +--------+------------------------------------------------------------------------------------------------------------------------------------------------------ -----+ 1 row in set (0.00 sec) mysql> mysql> mysql> create table t_ctas as select * from test1; Query OK, 1 row affected (0.03 sec) Records: 1 Duplicates: 0 Warnings: 0 mysql> select * from test1; +----+------+ | id | name | +----+------+ | 1 | abc | +----+------+ 1 row in set (0.00 sec) mysql> mysql> show create table t_ctas; +--------+----------------------------------------------------------------------------------------------------------------------------------+ | Table | Create Table | +--------+----------------------------------------------------------------------------------------------------------------------------------+ | t_ctas | CREATE TABLE `t_ctas` ( `id` int NOT NULL DEFAULT '0', `name` varchar(100) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8 | +--------+----------------------------------------------------------------------------------------------------------------------------------+ 1 row in set (0.00 sec)
复制

1.4 Column Data Types and Attributes

类别 描述
data_type 列数据类型
NOT NULL or NULL 是否可以为空
DEFAULT 给列一个默认值
AUTO_INCREMENT 自动增长
当你insert一个null or 0 到一个自增列,会自动生产序列的下一个值
COMMENT 注释语句
COLUMN_FORMAT 列的格式(NDB)
STORAGE 存储(NDB)
GENERATED ALWAYS 基于现有列生产的列
-- 测试 not null、default、auto_increment、comment create table user_info(id int primary key auto_increment comment '主键自增id',idcard varchar(50) not null comment '身份证号码',sex varchar(10) default '未知' comment '性别' ); show create table user_info\G insert into user_info(id,idcard,sex) values(0,'123456','男'); insert into user_info(id,idcard,sex) values(null,'123456',null); insert into user_info(id,idcard,sex) values(5,'123456','女'); -- insert的时候 没有指定 或者给null 和 0 的时候 自增列会是序列的下一个值 -- 当指定了之后,就是指定的值,而且序列的下一个值也会因为指定的这个值 而发生变化 select * from user_info; -- 对于有指定default的列 给''/null 都不会触发默认值,只有录入的时候不指定列 才会触发default条件 insert into user_info(id,idcard,sex) values(null,'123456',''); insert into user_info(id,idcard) values(null,'123456'); select * from user_info;
复制

执行记录:

mysql> create table user_info(id int primary key auto_increment comment '主键自增id',idcard varchar(50) not null comment '身份证号码',sex varchar(10) default ' 未知' comment '性别' ); Query OK, 0 rows affected (0.03 sec) mysql> mysql> show create table user_info\G *************************** 1. row *************************** Table: user_info Create Table: CREATE TABLE `user_info` ( `id` int NOT NULL AUTO_INCREMENT COMMENT '主键自增id', `idcard` varchar(50) NOT NULL COMMENT '身份证号码', `sex` varchar(10) DEFAULT '未知' COMMENT '性别', PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql> insert into user_info(id,idcard,sex) values(0,'123456','男'); Query OK, 1 row affected (0.01 sec) mysql> insert into user_info(id,idcard,sex) values(null,'123456',null); Query OK, 1 row affected (0.01 sec) mysql> insert into user_info(id,idcard,sex) values(5,'123456','女'); Query OK, 1 row affected (0.01 sec) mysql> select * from user_info; +----+--------+------+ | id | idcard | sex | +----+--------+------+ | 1 | 123456 | 男 | | 2 | 123456 | NULL | | 5 | 123456 | 女 | +----+--------+------+ 3 rows in set (0.00 sec) mysql> insert into user_info(id,idcard,sex) values(null,'123456',''); Query OK, 1 row affected (0.01 sec) mysql> select * from user_info; +----+--------+------+ | id | idcard | sex | +----+--------+------+ | 1 | 123456 | 男 | | 2 | 123456 | NULL | | 5 | 123456 | 女 | | 6 | 123456 | | +----+--------+------+ 4 rows in set (0.00 sec) mysql> insert into user_info(id,idcard) values(null,'123456'); Query OK, 1 row affected (0.01 sec) mysql> select * from user_info; +----+--------+---------+ | id | idcard | sex | +----+--------+---------+ | 1 | 123456 | 男 | | 2 | 123456 | NULL | | 5 | 123456 | 女 | | 6 | 123456 | | | 7 | 123456 | 未知 | +----+--------+---------+ 5 rows in set (0.00 sec)
复制

GENERATED ALWAYS

CREATE TABLE t4 ( first_name VARCHAR(10), last_name VARCHAR(10), full_name VARCHAR(255) AS (CONCAT(first_name,' ',last_name)) ); insert into t4(first_name,last_name) values ('马','云'); select * from t4; insert into t4(first_name,last_name,'full_name') values ('马','化腾','马化腾');
复制

执行记录:

mysql> CREATE TABLE t4 ( -> first_name VARCHAR(10), -> last_name VARCHAR(10), -> full_name VARCHAR(255) AS (CONCAT(first_name,' ',last_name)) -> ); Query OK, 0 rows affected (0.03 sec) mysql> insert into t4(first_name,last_name) values ('马','云'); Query OK, 1 row affected (0.01 sec) mysql> select * from t4; +------------+-----------+-----------+ | first_name | last_name | full_name | +------------+-----------+-----------+ | 马 | 云 | 马 云 | +------------+-----------+-----------+ 1 row in set (0.00 sec) mysql> insert into t4(first_name,last_name,'full_name') values ('马','化腾','马化腾'); ERROR 1064 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near ''full _name') values ('','化腾','马化腾')' at line 1 mysql>
复制

1.5 Indexes, Foreign Keys, and CHECK Constraints

类别 描述
CONSTRAINT 约束
PRIMARY KEY 主键约束
KEY or INDEX 索引 key是index的同义词
UNIQUE 唯一约束
FULLTEXT 全文索引
SPATIAL 空间索引
FOREIGN KEY 外键
CHECK 检查约束
key_part 升序or降序 前缀
index_type 索引类别
index_option KEY_BLOCK_SIZE、WITH PARSER、COMMENT
reference_definition 外键约束 指定主表的列

索引一般是创建表之后再创建,这个地方先略过,后面会单独写一个索引的blog

1.NOT NULL :非空,用于保证该字段的值不能为空。
2.DEFAULT:默认值,用于保证该字段有默认值。
3.PRIMARY KEY:主键,用于保证该字段的值具有唯一性并且非空。
4.UNIQUE:唯一,用于保证该字段的值具有唯一性,可以为空。
5.CHECK:检查约束,检查字段的值是否为指定的值。
6.FOREIGN KEY:外键,用于限制两个表的关系,用于保证该字段的值必须来自于主表的关联列的值,在从表添加外键约束,用于引用主表中某些的值。

create table user_info (id int primary key auto_increment comment '主键自增id', idcard varchar(50) unique not null comment '身份证号码' , sex varchar(10) check(sex = '男' or sex = '女') default '男' comment '性别' ); show create table user_info\G -- insert into user_info(id,idcard,sex) values (1,'123','abc'); insert into user_info(id,idcard,sex) values (0,'123','男'); insert into user_info(id,idcard,sex) values (0,'123',''); insert into user_info(id,idcard) values (0,'123'); insert into user_info(id,idcard) values (0,'456');
复制

执行记录:

mysql> create table user_info -> (id int primary key auto_increment comment '主键自增id', -> idcard varchar(50) unique not null comment '身份证号码' , -> sex varchar(10) check(sex = '男' or sex = '女') default '男' comment '性别' -> ); Query OK, 0 rows affected (0.03 sec) mysql> show create table user_info\G *************************** 1. row *************************** Table: user_info Create Table: CREATE TABLE `user_info` ( `id` int NOT NULL AUTO_INCREMENT COMMENT '主键自增id', `idcard` varchar(50) NOT NULL COMMENT '身份证号码', `sex` varchar(10) DEFAULT '男' COMMENT '性别', PRIMARY KEY (`id`), UNIQUE KEY `idcard` (`idcard`), CONSTRAINT `user_info_chk_1` CHECK (((`sex` = _utf8mb3'男') or (`sex` = _utf8mb3'女'))) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql> mysql> -- 违反 检查约束 mysql> insert into user_info(id,idcard,sex) values (1,'123','abc'); ERROR 3819 (HY000): Check constraint 'user_info_chk_1' is violated. -- 正常录入数据 mysql> insert into user_info(id,idcard,sex) values (0,'123','男'); Query OK, 1 row affected (0.01 sec) --''一样也违反检查约束,并不会触发default值 mysql> insert into user_info(id,idcard,sex) values (0,'123',''); ERROR 3819 (HY000): Check constraint 'user_info_chk_1' is violated. -- 违反idcard的唯一约束 mysql> insert into user_info(id,idcard) values (0,'123'); ERROR 1062 (23000): Duplicate entry '123' for key 'user_info.idcard' mysql> mysql> -- 正常录入数据 mysql> insert into user_info(id,idcard) values (0,'456'); Query OK, 1 row affected (0.01 sec)
复制

1.6 Table Options

类别 描述
ENGINE 指定存储引擎
AUTO_INCREMENT 自动增长
AVG_ROW_LENGTH 平均行长度
[DEFAULT] CHARACTER SET 指定字符集
CHECKSUM MyISAM引擎独有的 快速查找损坏的表
[DEFAULT] COLLATE 指定的排序规则
COMMENT 表的备注
COMPRESSION 表压缩
CONNECTION FEDERATED 存储引擎表 远程连接
DATA DIRECTORY, INDEX DIRECTORY 数据及索引目录
DELAY_KEY_WRITE 延迟更新索引到表关闭
ENCRYPTION 加密
INSERT_METHOD Merge存储引擎独有
KEY_BLOCK_SIZE index key blocks(MyISAM), 压缩表的page size(InnoDB)
MAX_ROWS 计划表录入最多的数据行数
MIN_ROWS 计划表录入最少的数据行数
PACK_KEYS MyISAM独有
PASSWORD 未使用
ROW_FORMAT 指定数据行的物理存储
STATS_AUTO_RECALC 统计信息相关
STATS_PERSISTENT 统计信息相关
STATS_SAMPLE_PAGES 统计信息相关
TABLESPACE 表空间
UNION 仅在Merge存储引擎的时候生效

1.6.1 ENGINE

常见存储引擎 InnoDB、MyISAM、MEMORY、CSV、ARCHIVE、EXAMPLE、FEDERATED、HEAP、MERGE、NDB
MySQL 8.0之后,连系统表也有MyISAM改为InnoDB,InnoDB已经可以覆盖大部分应用场景了
其它的存储引擎也有各自的使用场景,后面单独写一个blog来简单介绍存储引擎。

1.6.2 AVG_ROW_LENGTH MAX_ROWS

用来控制行的长度和行的总数。

1.6.3 CHARACTER SET COLLATE

字符集和排序规则,MySQL 字符集和排序规则

1.6.4 COMMENT

表的备注,根据规范,表都需要有备注信息

1.6.5 COMPRESSION

表的压缩,节约空间,但是会消耗select 和DML语句的性能
适用于不会被访问的历史归档数据

1.6.6 STATS_AUTO_RECALC STATS_PERSISTENT STATS_SAMPLE_PAGES

STATS_PERSISTENT
指定是否为InnoDB表启用持久统计信息。

DEFAULT:表示表的持久统计信息设置由innodb_stats_persistent配置选项确定
1:表示启用表的持久统计信息
0:关闭此功能

STATS_AUTO_RECALC
指定是否自动重新计算InnoDB表的持久统计信息。

DEFAULT:表示表的持久统计信息设置由innodb_stats_auto_recalc配置选项确定
1:表示表中10%的数据发生更改时将重新计算统计信息
0:禁用自动重新计算此表

STATS_SAMPLE_PAGES
指定在估计索引列的基数和其他统计信息时要采样的索引页数

1.7 Table Partitioning

分区又是另外一个范畴了,会单独开一个blog,此处略过

二.修改表

语法:

ALTER TABLE tbl_name [alter_option [, alter_option] ...] [partition_options] alter_option: { table_options | ADD [COLUMN] col_name column_definition [FIRST | AFTER col_name] | ADD [COLUMN] (col_name column_definition,...) | ADD {INDEX | KEY} [index_name] [index_type] (key_part,...) [index_option] ... | ADD {FULLTEXT | SPATIAL} [INDEX | KEY] [index_name] (key_part,...) [index_option] ... | ADD [CONSTRAINT [symbol]] PRIMARY KEY [index_type] (key_part,...) [index_option] ... | ADD [CONSTRAINT [symbol]] UNIQUE [INDEX | KEY] [index_name] [index_type] (key_part,...) [index_option] ... | ADD [CONSTRAINT [symbol]] FOREIGN KEY [index_name] (col_name,...) reference_definition | ADD [CONSTRAINT [symbol]] CHECK (expr) [[NOT] ENFORCED] | DROP {CHECK | CONSTRAINT} symbol | ALTER {CHECK | CONSTRAINT} symbol [NOT] ENFORCED | ALGORITHM [=] {DEFAULT | INSTANT | INPLACE | COPY} | ALTER [COLUMN] col_name {SET DEFAULT {literal | (expr)} | DROP DEFAULT} | ALTER INDEX index_name {VISIBLE | INVISIBLE} | CHANGE [COLUMN] old_col_name new_col_name column_definition [FIRST | AFTER col_name] | [DEFAULT] CHARACTER SET [=] charset_name [COLLATE [=] collation_name] | CONVERT TO CHARACTER SET charset_name [COLLATE collation_name] | {DISABLE | ENABLE} KEYS | {DISCARD | IMPORT} TABLESPACE | DROP [COLUMN] col_name | DROP {INDEX | KEY} index_name | DROP PRIMARY KEY | DROP FOREIGN KEY fk_symbol | FORCE | LOCK [=] {DEFAULT | NONE | SHARED | EXCLUSIVE} | MODIFY [COLUMN] col_name column_definition [FIRST | AFTER col_name] | ORDER BY col_name [, col_name] ... | RENAME COLUMN old_col_name TO new_col_name | RENAME {INDEX | KEY} old_index_name TO new_index_name | RENAME [TO | AS] new_tbl_name | {WITHOUT | WITH} VALIDATION } partition_options: partition_option [partition_option] ... partition_option: { ADD PARTITION (partition_definition) | DROP PARTITION partition_names | DISCARD PARTITION {partition_names | ALL} TABLESPACE | IMPORT PARTITION {partition_names | ALL} TABLESPACE | TRUNCATE PARTITION {partition_names | ALL} | COALESCE PARTITION number | REORGANIZE PARTITION partition_names INTO (partition_definitions) | EXCHANGE PARTITION partition_name WITH TABLE tbl_name [{WITH | WITHOUT} VALIDATION] | ANALYZE PARTITION {partition_names | ALL} | CHECK PARTITION {partition_names | ALL} | OPTIMIZE PARTITION {partition_names | ALL} | REBUILD PARTITION {partition_names | ALL} | REPAIR PARTITION {partition_names | ALL} | REMOVE PARTITIONING } key_part: {col_name [(length)] | (expr)} [ASC | DESC] index_type: USING {BTREE | HASH} index_option: { KEY_BLOCK_SIZE [=] value | index_type | WITH PARSER parser_name | COMMENT 'string' | {VISIBLE | INVISIBLE} } table_options: table_option [[,] table_option] ... table_option: { AUTO_INCREMENT [=] value | AVG_ROW_LENGTH [=] value | [DEFAULT] CHARACTER SET [=] charset_name | CHECKSUM [=] {0 | 1} | [DEFAULT] COLLATE [=] collation_name | COMMENT [=] 'string' | COMPRESSION [=] {'ZLIB' | 'LZ4' | 'NONE'} | CONNECTION [=] 'connect_string' | {DATA | INDEX} DIRECTORY [=] 'absolute path to directory' | DELAY_KEY_WRITE [=] {0 | 1} | ENCRYPTION [=] {'Y' | 'N'} | ENGINE [=] engine_name | INSERT_METHOD [=] { NO | FIRST | LAST } | KEY_BLOCK_SIZE [=] value | MAX_ROWS [=] value | MIN_ROWS [=] value | PACK_KEYS [=] {0 | 1 | DEFAULT} | PASSWORD [=] 'string' | ROW_FORMAT [=] {DEFAULT | DYNAMIC | FIXED | COMPRESSED | REDUNDANT | COMPACT} | STATS_AUTO_RECALC [=] {DEFAULT | 0 | 1} | STATS_PERSISTENT [=] {DEFAULT | 0 | 1} | STATS_SAMPLE_PAGES [=] value | TABLESPACE tablespace_name [STORAGE {DISK | MEMORY}] | UNION [=] (tbl_name[,tbl_name]...) } partition_options: (see CREATE TABLE options)
复制

2.1 修改表的存储引擎

语法:

-- 将非InnoDB存储引擎的表修改为 InnoDB存储引擎 ALTER TABLE t1 ENGINE = InnoDB;
复制

测试记录:

mysql> create table t_5(id int,name varchar(100)) engine MyISAM; Query OK, 0 rows affected (0.02 sec) mysql> mysql> show create table t_5\G *************************** 1. row *************************** Table: t_5 Create Table: CREATE TABLE `t_5` ( `id` int DEFAULT NULL, `name` varchar(100) DEFAULT NULL ) ENGINE=MyISAM DEFAULT CHARSET=utf8 1 row in set (0.01 sec) mysql> alter table t_5 engine InNODB; Query OK, 0 rows affected (0.06 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> show create table t_5\G *************************** 1. row *************************** Table: t_5 Create Table: CREATE TABLE `t_5` ( `id` int DEFAULT NULL, `name` varchar(100) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec)
复制

2.2 修改表自增值

语法:

-- 修改表的自增列值 ALTER TABLE t1 AUTO_INCREMENT = 13;
复制

测试记录:

mysql> create table t5(id int primary key auto_increment,name varchar(100)); Query OK, 0 rows affected (0.03 sec) mysql> insert into t5(id,name) values (0,'abc'); Query OK, 1 row affected (0.01 sec) mysql> select * from t5; +----+------+ | id | name | +----+------+ | 1 | abc | +----+------+ 1 row in set (0.00 sec) mysql> alter table t5 auto_increment = 99; Query OK, 0 rows affected (0.01 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> insert into t5(id,name) values (0,'abc'); Query OK, 1 row affected (0.01 sec) mysql> select * from t5; +----+------+ | id | name | +----+------+ | 1 | abc | | 99 | abc | +----+------+ 2 rows in set (0.00 sec) -- 修改为比99小的10 居然没有报错 mysql> alter table t5 auto_increment = 10; Query OK, 0 rows affected (0.01 sec) Records: 0 Duplicates: 0 Warnings: 0 -- 执行才知道 虽然修改语句没报错 但是木有生效 mysql> insert into t5(id,name) values (0,'abc'); Query OK, 1 row affected (0.01 sec) mysql> select * from t5; +-----+------+ | id | name | +-----+------+ | 1 | abc | | 99 | abc | | 100 | abc | +-----+------+ 3 rows in set (0.00 sec)
复制

2.3 修改表的字符集

语法:

-- 将表的字符集修改为utf8 ALTER TABLE t1 CHARACTER SET = utf8;
复制
mysql> create table t6(id int,name varchar(100)) character set = utf8mb4; Query OK, 0 rows affected (0.02 sec) mysql> alter table t6 character set = utf8; Query OK, 0 rows affected, 1 warning (0.01 sec) Records: 0 Duplicates: 0 Warnings: 1
复制

2.4 修改表的备注信息

语法:

-- 修改表备注信息 ALTER TABLE t1 COMMENT = 'New table comment';
复制

测试记录:

mysql> create table t7(id int,name varchar(100)) comment 'old comment'; Query OK, 0 rows affected (0.03 sec) mysql> show create table t7\G *************************** 1. row *************************** Table: t7 Create Table: CREATE TABLE `t7` ( `id` int DEFAULT NULL, `name` varchar(100) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COMMENT='old comment' 1 row in set (0.00 sec) mysql> alter table t7 comment = 'new comment'; Query OK, 0 rows affected (0.02 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> show create table t7\G *************************** 1. row *************************** Table: t7 Create Table: CREATE TABLE `t7` ( `id` int DEFAULT NULL, `name` varchar(100) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COMMENT='new comment' 1 row in set (0.00 sec)
复制

2.5 重命名、重新定义和重新排序列

1.change
可以重命名或重定义列,或者两者一起
2.modify
修改列定义,但是不能修改列名
对于修改列定义而言,比change更方便
3.rename
可以重命名列,但是不能修改列的定义
对于重命名而言,比change更方便

语法:

-- 将列调整为非空 ALTER TABLE t1 MODIFY b INT NOT NULL; -- 将列名由b修改为a ALTER TABLE t1 RENAME COLUMN b TO a; -- 修改col1列的定义 ALTER TABLE t1 MODIFY col1 BIGINT UNSIGNED DEFAULT 1 COMMENT 'my column';
复制

测试记录:

mysql> create table t8(id int,name1 varchar(10)); Query OK, 0 rows affected (0.03 sec) mysql> mysql> alter table t8 modify id int not null; Query OK, 0 rows affected (0.04 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> alter table t8 rename column name1 to name; Query OK, 0 rows affected (0.01 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> mysql> mysql> alter table t8 modify id bigint unsigned default 1 comment 'my column'; Query OK, 0 rows affected (0.06 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> mysql> show create table t8\G *************************** 1. row *************************** Table: t8 Create Table: CREATE TABLE `t8` ( `id` bigint unsigned DEFAULT '1' COMMENT 'my column', `name` varchar(10) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql>
复制

2.6 约束相关

`语法:

-- 删除主键约束 ALTER TABLE tbl_name DROP PRIMARY KEY; -- 新增约束 ALTER TABLE tbl_name ADD CONSTRAINT [symbol] CHECK (expr) [[NOT] ENFORCED]; -- 删除约束 ALTER TABLE tbl_name DROP CONSTRAINT symbol; ALTER TABLE tbl_name DROP CHECK symbol;
复制

测试记录:

mysql> create table t9(id int primary key,name1 varchar(10)); Query OK, 0 rows affected (0.02 sec) mysql> show create table t9\G *************************** 1. row *************************** Table: t9 Create Table: CREATE TABLE `t9` ( `id` int NOT NULL, `name1` varchar(10) DEFAULT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql> mysql> alter table t9 drop primary key; Query OK, 0 rows affected (0.04 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> alter table t9 add unique u1(name1); Query OK, 0 rows affected (0.02 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> show create table t9\G *************************** 1. row *************************** Table: t9 Create Table: CREATE TABLE `t9` ( `id` int NOT NULL, `name1` varchar(10) DEFAULT NULL, UNIQUE KEY `u1` (`name1`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql> alter table t9 drop constraint u1; Query OK, 0 rows affected (0.02 sec) Records: 0 Duplicates: 0 Warnings: 0
复制

2.7 修改表和列的字符集

语法:

-- 修改表默认的字符集 ALTER TABLE tbl_name DEFAULT CHARACTER SET charset_name; -- 修改列的字符集 ALTER TABLE t MODIFY latin1_text_col TEXT CHARACTER SET utf8;
复制

测试记录:

mysql> create table t10(id int,name varchar(100)); Query OK, 0 rows affected (0.03 sec) mysql> show create table t10\G *************************** 1. row *************************** Table: t10 Create Table: CREATE TABLE `t10` ( `id` int DEFAULT NULL, `name` varchar(100) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8 1 row in set (0.00 sec) mysql> mysql> mysql> alter table t10 default character set utf8mb4; Query OK, 0 rows affected (0.01 sec) Records: 0 Duplicates: 0 Warnings: 0 mysql> show create table t10\G *************************** 1. row *************************** Table: t10 Create Table: CREATE TABLE `t10` ( `id` int DEFAULT NULL, `name` varchar(100) CHARACTER SET utf8 DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci 1 row in set (0.00 sec) mysql> mysql> mysql> mysql> alter table t10 modify name varchar(100) character set utf8; Query OK, 0 rows affected, 1 warning (0.01 sec) Records: 0 Duplicates: 0 Warnings: 1
复制

三.删除表

语法:

DROP [TEMPORARY] TABLE [IF EXISTS] tbl_name [, tbl_name] ... [RESTRICT | CASCADE]
复制

测试记录:

mysql> drop table t1; Query OK, 0 rows affected (0.02 sec) mysql> drop table t11; ERROR 1051 (42S02): Unknown table 'test1.t11' mysql> mysql> mysql> drop table if exists t11; Query OK, 0 rows affected, 1 warning (0.01 sec) mysql> mysql> show warnings; +-------+------+---------------------------+ | Level | Code | Message | +-------+------+---------------------------+ | Note | 1051 | Unknown table 'test1.t11' | +-------+------+---------------------------+ 1 row in set (0.00 sec) mysql> mysql> mysql> drop table t2,t3,t4,t5,t6,t7,t8,t9,t10; Query OK, 0 rows affected (0.08 sec)
复制
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

文章被以下合辑收录

评论

TA的专栏
大数据及数据仓库
收录239篇内容
Redis从小白到小工
收录19篇内容
MySQL开发
收录24篇内容
目录
  • 一.创建表
    • 1.1 Table Name
    • 1.2 Temporary Tables
    • 1.3 Table Cloning and Copying
    • 1.4 Column Data Types and Attributes
    • 1.5 Indexes, Foreign Keys, and CHECK Constraints
    • 1.6 Table Options
      • 1.6.1 ENGINE
      • 1.6.2 AVG_ROW_LENGTH MAX_ROWS
    • 1.6.3 CHARACTER SET COLLATE
    • 1.6.4 COMMENT
    • 1.6.5 COMPRESSION
    • 1.6.6 STATS_AUTO_RECALC STATS_PERSISTENT STATS_SAMPLE_PAGES
    • 1.7 Table Partitioning
  • 二.修改表
    • 2.1 修改表的存储引擎
    • 2.2 修改表自增值
    • 2.3 修改表的字符集
    • 2.4 修改表的备注信息
    • 2.5 重命名、重新定义和重新排序列
    • 2.6 约束相关
    • 2.7 修改表和列的字符集
  • 三.删除表