概述
一、MySQL 的方式(AUTO_INCREMENT)
MogDB=# SELECT current_database();
current_database
------------------
postgres
(1 row)
MogDB=# \l postgres
List of databases
Name | Owner | Encoding | Collate | Ctype | Access privileges | Compatibility
----------+-------+----------+---------+-------+-------------------+---------------
postgres | om5 | UTF8 | C | C | | A
(1 row)
MogDB=# CREATE TABLE test_create_autoinc(id bool auto_increment primary key, name varchar(200),a int) auto_increment=1;
ERROR: auto_increment is supported only in B-format database
MogDB=#
正确的使用方式如下:
MogDB=# create database db_mysql with dbcompatibility ='B';
CREATE DATABASE
MogDB=# \c db_mysql
Non-SSL connection (SSL connection is recommended when requiring high-security)
You are now connected to database "db_mysql" as user "om5".
db_mysql=# CREATE TABLE test_create_autoinc_source(id int auto_increment primary key) AUTO_INCREMENT = 100;
NOTICE: CREATE TABLE will create implicit sequence "test_create_autoinc_source_id_seq" for serial column "test_create_autoinc_source.id"
NOTICE: CREATE TABLE PRIMARY KEY will create implicit index "test_create_autoinc_source_pkey" for table "test_create_autoinc_source"
CREATE TABLE
db_mysql=# \d test_create_autoinc_source
Table "public.test_create_autoinc_source"
Column | Type | Modifiers
--------+---------+-------------------------
id | integer | not null AUTO_INCREMENT
Indexes:
"test_create_autoinc_source_pkey" PRIMARY KEY, btree (id) TABLESPACE pg_default
--->插入值进行验证
db_mysql=# INSERT INTO test_create_autoinc_source VALUES(DEFAULT);
INSERT 0 1
db_mysql=# INSERT INTO test_create_autoinc_source VALUES(DEFAULT);
INSERT 0 1
db_mysql=# SELECT id FROM test_create_autoinc_source ORDER BY 1;
id
-----
100
101
(2 rows)
二、PostgreSQL 的方式(SERIAL)
方式一
MogDB=# create table test_serial_a1(
id serial,
name character varying(256),
constraint pk_test_serial_id primary key( id)
);
NOTICE: CREATE TABLE will create implicit sequence "test_serial_a1_id_seq" for serial column "test_serial_a1.id"
NOTICE: CREATE TABLE PRIMARY KEY will create implicit index "pk_test_serial_id" for table "test_serial_a1"
CREATE TABLE
MogDB=# \d test_serial_a1
Table "public.test_serial_a1"
Column | Type | Modifiers
--------+------------------------+-------------------------------------------------------------
id | integer | not null default nextval('test_serial_a1_id_seq'::regclass)
name | character varying(256) |
Indexes:
"pk_test_serial_id" PRIMARY KEY, btree (id) TABLESPACE pg_default
MogDB=# \d test_serial_a1_id_seq
Sequence "public.test_serial_a1_id_seq"
Column | Type | Value
---------------+---------+-----------------------
sequence_name | name | test_serial_a1_id_seq
last_value | bigint | 2
start_value | bigint | 1
increment_by | bigint | 1
max_value | bigint | 9223372036854775807
min_value | bigint | 1
cache_value | bigint | 1
log_cnt | bigint | 31
is_cycled | boolean | f
is_called | boolean | t
uuid | bigint | 0
Owned by: public.test_serial_a1.id
--->插入值进行验证
MogDB=# insert into test_serial_a1 values(DEFAULT,'no1');
INSERT 0 1
MogDB=# insert into test_serial_a1 values(DEFAULT,'no1');
INSERT 0 1
MogDB=# SELECT * FROM test_serial_a1;
id | name
----+------
1 | no1
2 | no1
(2 rows)
方式二
MogDB=# create table test_serial_a2(
id serial PRIMARY KEY,
name character varying(256)
);
NOTICE: CREATE TABLE will create implicit sequence "test_serial_a2_id_seq" for serial column "test_serial_a2.id"
NOTICE: CREATE TABLE PRIMARY KEY will create implicit index "test_serial_a2_pkey" for table "test_serial_a2"
CREATE TABLE
MogDB=# \d test_serial_a2
Table "public.test_serial_a2"
Column | Type | Modifiers
--------+------------------------+-------------------------------------------------------------
id | integer | not null default nextval('test_serial_a2_id_seq'::regclass)
name | character varying(256) |
Indexes:
"test_serial_a2_pkey" PRIMARY KEY, btree (id) TABLESPACE pg_default
--->插入值进行验证
MogDB=# insert into test_serial_a2 values(DEFAULT,'no1');
INSERT 0 1
MogDB=# insert into test_serial_a2 values(DEFAULT,'no1');
INSERT 0 1
MogDB=# SELECT * FROM test_serial_a2;
id | name
----+------
1 | no1
2 | no1
(2 rows)
这两种方法用的是 PostgreSQL 的serial类型实现自增,drop表的时候指定的序列也会drop掉。
三、基于序列
1.手动创建序列
MogDB=# CREATE SEQUENCE test_aaa_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
CREATE SEQUENCE
MogDB=# \d test_aaa_id_seq
Sequence "public.test_aaa_id_seq"
Column | Type | Value
---------------+---------+---------------------
sequence_name | name | test_aaa_id_seq
last_value | bigint | 1
start_value | bigint | 1
increment_by | bigint | 1
max_value | bigint | 9223372036854775807
min_value | bigint | 1
cache_value | bigint | 1
log_cnt | bigint | 0
is_cycled | boolean | f
is_called | boolean | f
uuid | bigint | 0
2.创建主键表
MogDB=# create table test_bbb (
id integer PRIMARY KEY default nextval('test_aaa_id_seq'::regclass),
name character varying(128)
);
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "test_bbb_pkey" for table "test_bbb"
CREATE TABLE
MogDB=# \d test_bbb
Table "public.test_bbb"
Column | Type | Modifiers
--------+------------------------+-------------------------------------------------------
id | integer | not null default nextval('test_aaa_id_seq'::regclass)
name | character varying(128) |
Indexes:
"test_bbb_pkey" PRIMARY KEY, btree (id) TABLESPACE pg_default
--->插入值进行验证
MogDB=# insert into test_bbb values(DEFAULT,'no1');
INSERT 0 1
MogDB=# insert into test_bbb values(DEFAULT,'no2');
INSERT 0 1
MogDB=# select * from test_bbb;
id | name
----+------
1 | no1
2 | no2
(2 rows)
alter table test_aaa alter column id set default nextval('test_aaa_id_seq');
这种自行使用序列的方法在drop表的时候序列不会随着drop掉。

“
作者简介
/ Author Introduction
阎书利 / 云和恩墨PG技术顾问
PostgreSQL ACE,《快速掌握 PostgreSQL 版本新特性》一书副主编,中国PG分会认证讲师,PGfans 2021年度MVP,Gauss松鼠会2021年度优秀会员,拥有PGCM、OCP(MySQL)等十多项数据库认证。目前主要从事于 PostgreSQL、openGauss / MogDB 的运维以及去O工作。


数据驱动,成就未来,云和恩墨,不负所托!
云和恩墨创立于2011年,以“数据驱动,成就未来”为使命,是智能的数据技术提供商。我们致力于将数据技术带给每个行业、每个组织、每个人,构建数据驱动的智能未来。
云和恩墨在数据承载(分布式存储、数据持续保护)、管理(数据库基础软件、数据库云管平台、数据技术服务)、加工(应用开发质量管控、数据模型管控、数字化转型咨询)和应用(数据服务化管理平台、数据智能分析处理、隐私计算)等领域为各个组织提供可信赖的产品、服务和解决方案,围绕用户需求,持续为客户创造价值,激发数据潜能,为成就未来敏捷高效的数字世界而不懈努力。

文章转载自云和恩墨,如果涉嫌侵权,请发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。