CREATE SEQUENCE
Defines a new sequence generator.
Synopsis
CREATE [TEMPORARY | TEMP] SEQUENCE <name>
[INCREMENT [BY] <value>]
[MINVALUE <minvalue> | NO MINVALUE]
[MAXVALUE <maxvalue> | NO MAXVALUE]
[START [ WITH ] <start>]
[CACHE <cache>]
[[NO] CYCLE]
[OWNED BY { <table>.<column> | NONE }]
Description
CREATE SEQUENCE
creates a new sequence number generator. This involves creating and initializing a new special single-row table. The generator will be owned by the user issuing the command.
If a schema name is given, then the sequence is created in the specified schema. Otherwise it is created in the current schema. Temporary sequences exist in a special schema, so a schema name may not be given when creating a temporary sequence. The sequence name must be distinct from the name of any other sequence, table, or view in the same schema.
After a sequence is created, you use the nextval()
function to operate on the sequence. For example, to insert a row into a table that gets the next value of a sequence:
INSERT INTO distributors VALUES (nextval('myserial'), 'acme');
You can also use the function setval()
to operate on a sequence, but only for queries that do not operate on distributed data. For example, the following query is allowed because it resets the sequence counter value for the sequence generator process on the master:
SELECT setval('myserial', 201);
But the following query will be rejected in HAWQ because it operates on distributed data:
INSERT INTO product VALUES (setval('myserial', 201), 'gizmo');
In a regular (non-distributed) database, functions that operate on the sequence go to the local sequence table to get values as they are needed. In HAWQ, however, keep in mind that each segment is its own distinct database process. Therefore the segments need a single point of truth to go for sequence values so that all segments get incremented correctly and the sequence moves forward in the right order. A sequence server process runs on the master and is the point-of-truth for a sequence in a HAWQ distributed database. Segments get sequence values at runtime from the master.
Because of this distributed sequence design, there are some limitations on the functions that operate on a sequence in HAWQ:
-
lastval()
andcurrval()
functions are not supported. -
setval()
can only be used to set the value of the sequence generator on the master, it cannot be used in subqueries to update records on distributed table data. -
nextval()
sometimes grabs a block of values from the master for a segment to use, depending on the query. So values may sometimes be skipped in the sequence if all of the block turns out not to be needed at the segment level. Note that a regular PostgreSQL database does this too, so this is not something unique to HAWQ.
Although you cannot update a sequence directly, you can use a query like:
SELECT * FROM <sequence_name>;
to examine the parameters and current state of a sequence. In particular, the last_value
field of the sequence shows the last value allocated by any session.
Parameters
NO MINVALUE
NO MINVALUE
is specified, then defaults will be used. The defaults are 1 and -263-1 for ascending and descending sequences, respectively.NO MAXVALUE
NO MAXVALUE
is specified, then default values will be used. The defaults are 263-1 and -1 for ascending and descending sequences, respectively.NO CYCLE
NO CYCLE
is specified, any calls to nextval
after the sequence has reached its maximum value will return an error. If not specified, NO CYCLE
is the default.OWNED BY NONE
OWNED BY NONE
, the default, specifies that there is no such association.Notes
Sequences are based on bigint arithmetic, so the range cannot exceed the range of an eight-byte integer (-9223372036854775808 to 9223372036854775807).
Although multiple sessions are guaranteed to allocate distinct sequence values, the values may be generated out of sequence when all the sessions are considered. For example, session A might reserve values 1..10 and return nextval=1
, then session B might reserve values 11..20 and return nextval=11
before session A has generated nextval=2
. Thus, you should only assume that the nextval()
values are all distinct, not that they are generated purely sequentially. Also,last_value
will reflect the latest value reserved by any session, whether or not it has yet been returned by nextval()
.
Examples
Create a sequence named myseq
:
CREATE SEQUENCE myseq START 101;
Insert a row into a table that gets the next value:
INSERT INTO distributors VALUES (nextval('myseq'), 'acme');
Reset the sequence counter value on the master:
SELECT setval('myseq', 201);
Illegal use of setval()
in HAWQ (setting sequence values on distributed data):
INSERT INTO product VALUES (setval('myseq', 201), 'gizmo');
Compatibility
CREATE SEQUENCE
conforms to the SQL standard, with the following exceptions:
- The
AS data_type
expression specified in the SQL standard is not supported. - Obtaining the next value is done using the
nextval()
function instead of theNEXT VALUE FOR
expression specified in the SQL standard. - The
OWNED BY
clause is a HAWQ extension.