This section describes EnterpriseDB's functions
for operating on sequence objects.
Sequence objects (also called sequence generators or
just sequences) are special single-row tables created with
CREATE SEQUENCE. A sequence object is usually used to
generate unique identifiers for rows of a table. The sequence functions,
listed in Table 8-28,
provide simple, multiuser-safe methods for obtaining successive
sequence values from sequence objects.
There are two ways to operate on sequences in EnterpriseDB.
The historical manner described below and the redwood compatible manner
discussed later in the chapter Section 8.9.1.
Table 8-28. Sequence Functions
Function | Return Type | Description |
---|
nextval (TEXT) | BIGINT | Advance sequence and return new value |
currval (TEXT) | BIGINT | Return value most recently obtained with nextval |
setval (TEXT, BIGINT) | BIGINT | Set sequence's current value |
setval (TEXT, BIGINT, BOOLEAN) | BIGINT | Set sequence's current value and is_called flag |
For largely historical reasons, the sequence to be operated on by a
sequence-function call is specified by a text-string argument. To
achieve some compatibility with the handling of ordinary
SQL names, the sequence functions convert their
argument to lowercase unless the string is double-quoted. Thus
nextval('foo') operates on sequence foo
nextval('FOO') operates on sequence foo
nextval('"Foo"') operates on sequence Foo
The sequence name can be schema-qualified if necessary:
nextval('myschema.foo') operates on myschema.foo
nextval('"myschema".foo') same as above
nextval('foo') searches search path for foo
Of course, the text argument can be the result of an expression,
not only a simple literal, which is occasionally useful.
The available sequence functions are:
nextval
Advance the sequence object to its next value and return that
value. This is done atomically: even if multiple sessions
execute nextval
concurrently, each will safely receive
a distinct sequence value.
currval
Return the value most recently obtained by nextval
for this sequence in the current session. (An error is
reported if nextval
has never been called for this
sequence in this session.) Notice that because this is returning
a session-local value, it gives a predictable answer even if other
sessions are executing nextval
meanwhile.
setval
Reset the sequence object's counter value. The two-parameter
form sets the sequence's last_value field to the specified
value and sets its is_called field to true,
meaning that the next nextval
will advance the sequence
before returning a value. In the three-parameter form,
is_called may be set either true or
false. If it's set to false,
the next nextval
will return exactly the specified
value, and sequence advancement commences with the following
nextval
. For example,
SELECT setval('foo', 42) FROM DUAL; Next nextval
will return 43
SELECT setval('foo', 42, true) FROM DUAL; Same as above
SELECT setval('foo', 42, false) FROM DUAL; Next nextval
will return 42
The result returned by setval
is just the value of its
second argument.
Important: To avoid blocking of 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, even if the
transaction that did the nextval
later aborts. This means
that aborted transactions may leave unused "holes" in the
sequence of assigned values. setval
operations are never
rolled back, either.
If a sequence object has been created with default parameters,
nextval
calls on it will return successive values
beginning with 1. Other behaviors can be obtained by using
special parameters in the CREATE SEQUENCE command;
see its command reference page for more information.
EnterpriseDB also provides redwood compatible sequence operations.
A sequence can be operated upon in the following manner as well:
sequence.CURRVAL
sequence.NEXTVAL
Hence we have the option to call the next value of the sequence 'foo' in the following manner:
SELECT foo.nextval;
The above statement will have the same effect as the statement:
SELECT nextval('foo');
The following example will demonstrate the prowess of sequences:
CREATE SEQUENCE foo;
CREATE TABLE test_tb ( a integer, b integer default foo.nextval);
INSERT INTO test_tb (a) values (1);
INSERT INTO test_tb (a) values (1);
INSERT INTO test_tb (a) values (1);
Here we have created a sequence foo
, and a table
test_tb. We have made three insertions in the table.
We will get the following result, once we execute the SQL statement.
SELECT * FROM test_tb;
The result will be:
a | b
--------|-----------
1 | 1
1 | 2
1 | 3