This page in other versions: 9.0 / 9.1 / 9.2 / 9.3 / 9.4  |  Development versions: devel  |  Unsupported versions: 7.2 / 7.3 / 7.4 / 8.0 / 8.1 / 8.2 / 8.3 / 8.4

9.11. Sequence-Manipulation Functions

This section describes PostgreSQL'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 9-34, provide simple, multiuser-safe methods for obtaining successive sequence values from sequence objects.

Table 9-34. 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 lower case 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);           Next nextval will return 43
SELECT setval('foo', 42, true);     Same as above
SELECT setval('foo', 42, false);    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.

Comments


Aug. 5, 2004, 8:18 a.m.

If you get the error:
ERROR: the_seq.currval is not yet defined in this session

You can use the following sub select to acheive the same result as currval:
SELECT last_value FROM the_seq;

eg:
INSERT INTO a_table VALUES ((SELECT last_value FROM dml_seq));


Dec. 17, 2004, 5:22 p.m.

The query suggested by a previous poster

SELECT last_value FROM the_seq;

might not always do what you want. For example, when the table is brand new, or when setval(x,false) has been called, it will return the next value, not the last value:

CREATE SEQUENCE the_seq MINVALUE 0;
SELECT last_value FROM the_seq; returns 0
SELECT nextval(\'the_seq\'); returns 0
SELECT last_value FROM the_seq; returns 0

The following query is a little smarter:

SELECT CASE WHEN is_called THEN last_value
ELSE last_value-increment_by END from the_seq;

This would return -1 immediately after the table creation above,
and not return 0 until after the first call to nextval(). However, if your sequence ever cycles this probably doesn\'t do the right thing either.


March 29, 2005, 11:04 a.m.

Be warned that if you try updating multiple rows with nextval(), the nextval operator will only be evaluated once at the beginning of the update instead of once for each row. In other words, if you run the following:

UPDATE foo SET bar=nextval('my_sequence');

Then each row's "bar" will be set to the same value, not incrementing values. This is because the "nextval" function is not marked as "volatile", so the parser optimizes it out.

The easiest way to set a field to incrementing values is to do this:

CREATE FUNCTION volatile_nextval(text) RETURNS bigint VOLATILE AS 'BEGIN RETURN nextval($1); END;' LANGUAGE 'plpgsql';
UPDATE foo SET bar=volatile_nextval('my_sequence');

Be warned that the order that rows are updated cannot be controlled, so although this will result in "bar" having unique values for each row, you can't guarantee what order they'll be in.


Nov. 28, 2005, 3:34 p.m.

Using postgresql 7.4.9 (Debian) I see the following behaviour:

my=> select currval('my_seq');
currval
---------
2
(1 row)

my=> update personen_status set my_id = nextval('my_sequence') ;
UPDATE 2
my=> select my_id from my_table;
my_id
-------
3
4
(2 rows)

my=>

Perhaps the table is too small, but I'd have expected the optimizer to always optimize the call away. I tried it with a bigger table (~250000 rows) too and couldn't reproduce JazFresh' problem.

Privacy Policy | About PostgreSQL
Copyright © 1996-2014 The PostgreSQL Global Development Group