9.17. Sequence Manipulation Functions
This section describes functions for operating on sequence objects , also called sequence generators or just sequences. Sequence objects are special single-row tables created with CREATE SEQUENCE . Sequence objects are commonly used to generate unique identifiers for rows of a table. The sequence functions, listed in Table 9.50 , provide simple, multiuser-safe methods for obtaining successive sequence values from sequence objects.
Table 9.50. Sequence Functions
Function Description |
---|
Advances the sequence object to its next value and returns that value.
This is done atomically: even if multiple sessions
execute
This function requires
|
Sets the sequence object's current value, and optionally
its
SELECT setval('myseq', 42); Next
The result returned by
This function requires
|
Returns the value most recently obtained
by
This function requires
|
Returns the value most recently returned by
This function requires
|
Caution
To avoid blocking concurrent transactions that obtain numbers from
the same sequence, a
nextval
operation is never
rolled back; that is, once a value has been fetched it is considered
used and will not be returned again. This is true even if the
surrounding transaction later aborts, or if the calling query ends
up not using the value. For example an
INSERT
with
an
ON CONFLICT
clause will compute the to-be-inserted
tuple, including doing any required
nextval
calls, before detecting any conflict that would cause it to follow
the
ON CONFLICT
rule instead. Such cases will leave
unused
"
holes
"
in the sequence of assigned values.
Thus,
PostgreSQL
sequence
objects
cannot be used to obtain
"
gapless
"
sequences
.
Likewise, any sequence state changes made by
setval
are not undone if the transaction rolls back.
The sequence to be operated on by a sequence function is specified by
a
regclass
argument, which is simply the OID of the sequence in the
pg_class
system catalog. You do not have to look up the
OID by hand, however, since the
regclass
data type's input
converter will do the work for you. Just write the sequence name enclosed
in single quotes so that it looks like a literal constant. For
compatibility with the handling of ordinary
SQL
names, the string will be converted to lower case
unless it contains double quotes around the sequence name. Thus:
nextval('foo') operates on sequencefoo
nextval('FOO') operates on sequencefoo
nextval('"Foo"') operates on sequenceFoo
The sequence name can be schema-qualified if necessary:
nextval('myschema.foo') operates onmyschema.foo
nextval('"myschema".foo') same as above nextval('foo') searches search path forfoo
See
Section 8.19
for more information about
regclass
.
Note
Before
PostgreSQL
8.1, the arguments of the
sequence functions were of type
text
, not
regclass
, and
the above-described conversion from a text string to an OID value would
happen at run time during each call. For backward compatibility, this
facility still exists, but internally it is now handled as an implicit
coercion from
text
to
regclass
before the function is
invoked.
When you write the argument of a sequence function as an unadorned
literal string, it becomes a constant of type
regclass
.
Since this is really just an OID, it will track the originally
identified sequence despite later renaming, schema reassignment,
etc. This
"
early binding
"
behavior is usually desirable for
sequence references in column defaults and views. But sometimes you might
want
"
late binding
"
where the sequence reference is resolved
at run time. To get late-binding behavior, force the constant to be
stored as a
text
constant instead of
regclass
:
nextval('foo'::text) foo
is looked up at runtime
Note that late binding was the only behavior supported in PostgreSQL releases before 8.1, so you might need to do this to preserve the semantics of old applications.
Of course, the argument of a sequence function can be an expression as well as a constant. If it is a text expression then the implicit coercion will result in a run-time lookup.