CREATE SEQUENCE adds a sequence to the current database. The owner of a sequence is the user who creates the sequence.
1 2 3 4 | CREATE SEQUENCE name [ INCREMENT [ BY ] increment ] [ MINVALUE minvalue | NO MINVALUE | NOMINVALUE ] [ MAXVALUE maxvalue | NO MAXVALUE | NOMAXVALUE] [ START [ WITH ] start ] [ CACHE cache ] [ [ NO ] CYCLE | NOCYCLE ] [ OWNED BY { table_name.column_name | NONE } ]; |
Specifies the name of a sequence to be created.
Value range: The value can contain only lowercase letters, uppercase letters, special characters #_$, and digits.
Specifies the step for a sequence. A positive generates an ascending sequence, and a negative generates a decreasing sequence.
The default value is 1.
Specifies the minimum value of a sequence. If MINVALUE is not declared, or NO MINVALUE is declared, the default value of the ascending sequence is 1, and that of the descending sequence is -263-1. NOMINVALUE is equivalent to NO MINVALUE.
Specifies the maximum value of a sequence. If MAXVALUE is not declared or NO MAXVALUE is declared, the default value of the ascending sequence is 263-1, and that of the descending sequence is -1. NOMAXVALUE is equivalent to NO MAXVALUE.
Specifies the start value of the sequence. The default value for ascending sequences is minvalue and for descending sequences maxvalue.
Specifies the number of sequence numbers stored in the memory for quick access. Within a cache period, the CN does not request a sequence number from the GTM. Instead, the CN uses the sequence number that is locally applied for in advance.
Default value 1 indicates that one value can be generated each time.
Used to ensure that sequences can recycle after the number of sequences reaches maxvalue or minvalue.
If you declare NO CYCLE, any invocation of nextval would return an error after the sequence reaches its maximum value.
NOCYCLE is equivalent to NO CYCLE.
The default value is NO CYCLE.
If the sequence is defined as CYCLE, the sequence uniqueness cannot be ensured.
Associates a sequence with a specified column included in a table. In this way, the sequence will be deleted when you delete its associated field or the table where the field belongs. The associated table and sequence must be owned by the same user and in the same schema. OWNED BY only establishes the association between a table column and the sequence. The sequence is not created for this column.
If the default value is OWNED BY NONE, indicating that such association does not exist.
You are not advised to use the sequence created using OWNED BY in other tables. If multiple tables need to share a sequence, the sequence must not belong to a specific table.
Create an ascending sequence named serial, which starts from 101:
1 2 3 | CREATE SEQUENCE serial START 101 CACHE 20; |
Select the next number from the sequence:
1 2 3 4 | SELECT nextval('serial'); nextval --------- 101 |
Select the next number from the sequence:
1 2 3 4 | SELECT nextval('serial'); nextval --------- 102 |
Create a sequence associated with the table:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 | CREATE TABLE customer_address ( ca_address_sk integer not null, ca_address_id char(16) not null, ca_street_number char(10) , ca_street_name varchar(60) , ca_street_type char(15) , ca_suite_number char(10) , ca_city varchar(60) , ca_county varchar(30) , ca_state char(2) , ca_zip char(10) , ca_country varchar(20) , ca_gmt_offset decimal(5,2) , ca_location_type char(20) ) ; CREATE SEQUENCE serial1 START 101 CACHE 20 OWNED BY customer_address.ca_address_sk; |
Use SERIAL to create a serial table serial_table for primary key auto-increment.
1 2 3 4 5 6 7 8 9 | CREATE TABLE serial_table(a int, b serial); INSERT INTO serial_table (a) VALUES (1),(2),(3); SELECT * FROM serial_table ORDER BY b; a | b ---+--- 1 | 1 2 | 2 3 | 3 (3 rows) |