PostgreSQL提供了两种方式用来进行表复制:
1、create table as
2、create table like
数据准备
创建含有序列、主键、注释、CHECK约束的tmp表用于后续测试:
create table tmp(id SERIAL,name VARCHAR(100) primary key,num int CHECK(10<num and num<100)
);
comment on column tmp.id is '标识码';
comment on column tmp.name is '名称';
comment on column tmp.num is '数量';insert into tmp(name,num) VALUES('苹果',61);
insert into tmp(name,num) VALUES('香蕉',51);
表的DDL展示:
下面就来讲讲两种表复制方式的结果:
create table as
挺常规的方法,在复制表结构的时候还可以带上数据。不过这种复制会丢失原有表的注释、约束等信息。
create table tmp_x as select * from tmp where name='苹果';
DDL:
create table like
语法:create table tar_table LIKE source_table [ like_option ... ]
like_option有下列几种选择:
1、INCLUDING COMMENTS
:注释
2、INCLUDING CONSTRAINTS
:CHECK约束
3、INCLUDING DEFAULTS
:被拷贝的列定义的默认表达式才会被拷贝。默认的行为是排除默认表达式,导致新表中被拷贝过来的列的默认值为空值。注意,如果拷贝的默认值调用了数据库修改函数(如nextval),则可能在原始表和新表之间创建功能联系。
4、INCLUDING IDENTITY
:拷贝复制字段定义的标识声明。 为新表的每个标识列创建一个新的序列,与旧表相关的序列区分开。
5、INCLUDING INDEXES
:主键约束 和索引约束
6、INCLUDING STORAGE
:复制而来的列定义的STORAGE设置才会被复制。默认行为会排除STORAGE设置,导致新表中复制而来的列具有与类型相关的默认设置
7、INCLUDING STATISTICS
:扩展统计会被复制到新表
8、INCLUDING ALL
:是 INCLUDING COMMENTS INCLUDING CONSTRAINTS INCLUDING DEFAULTS INCLUDING IDENTITY INCLUDING INDEXES INCLUDING STATISTICS INCLUDING STORAGE.的简写形式。
一般我们复制时只用 INCLUDING COMMENTS INCLUDING CONSTRAINTS INCLUDING INDEXES就够了。
示例1:
create table tmp_a (like tmp);
示例2:
只使用INCLUDING DEFAULTS拷贝列定义
create table tmp_b (like tmp INCLUDING defaults);
示例3:
使用INCLUDING COMMENTS INCLUDING CONSTRAINTS INCLUDING INDEXES拷贝注释、约束
create table tmp_c (like tmp INCLUDING comments including constraints including indexes);
各种拷贝结果的DDL:
示例1 | 示例2 | 示例3 |
PostgreSQL 11.2 手册
春江潮水连海平,海上明月共潮生。 --张若虚《春江花月夜》