This topic describes how to define a new sequence generator.

Syntax

CREATE SEQUENCE name [ INCREMENT BY increment ]
  [ { NOMINVALUE | MINVALUE minvalue } ]
  [ { NOMAXVALUE | MAXVALUE maxvalue } ]
  [ START WITH start ] [ CACHE cache | NOCACHE ] [ CYCLE ]

Parameters

Parameter Description
name The name (optionally schema-qualified) of the sequence to be created.
increment The optional clause INCREMENT BY increment specifies the value to add to the current sequence value to create a new value. A positive value will make an ascending sequence, a negative one a descending sequence. The default value is 1.
NOMINVALUE | MINVALUE minvalue The optional clause MINVALUE minvalue determines the minimum value a sequence can generate. If this clause is not supplied, then default values will be used. The default values are 1 and -2 63 -1 for ascending and descending sequences respectively. Note that the keyword NOMINVALUE may be used to set this behavior to the default.
NOMAXVALUE | MAXVALUE maxvalue The optional clause MAXVALUE maxvalue determines the maximum value for the sequence. If this clause is not supplied, then default values will be used. The default values are 2 63 -1 and 1 for ascending and descending sequences respectively. Note that the keyword NOMAXVALUE may be used to set this behavior to the default.
start The optional clause START WITH start allows the sequence to begin anywhere. The default starting value is minvalue for ascending sequences and maxvalue for descending ones.
cache The optional clause CACHE cache specifies how many sequence numbers are to be preallocated and stored in memory for faster access. The minimum value is 1 (only one value can be generated at a time such as NOCACHE), and this is also the default.
CYCLE The CYCLE option allows the sequence to wrap around when the maxvalue or minvalue has been reached by an ascending or descending sequence respectively. If the limit is reached, the next number generated will be the minvalue or maxvalue respectively. If the default value CYCLE is omitted, any calls to NEXTVAL after the sequence has reached its maximum value will return an error. Note that the keyword NO CYCLE may be used to obtain the default behavior, however, this keyword is not compatible with Oracle databases.

Description

The CREATE SEQUENCE statement is used to define a new sequence generator. This involves creating and initializing a new special single-row table with the name parameter. The generator will be owned by the user issuing the statement.

If a schema name is given then the sequence is created in the specified schema, otherwise it is created in the current schema. The sequence name must be distinct from the name of any other sequence, table, index, or view in the same schema.

Note

Sequences are based on big integer arithmetic, so the range cannot exceed the range of an eight-byte integer (-9223372036854775808 to 9223372036854775807). On some earlier platforms, there may be no compiler support for eight-byte integers, in which case sequences use regular INTEGER arithmetic (range -2147483648 to +2147483647).

Unexpected results may be obtained if a cache setting greater than one is used for a sequence object that will be used concurrently by multiple sessions. Unexpected results may be obtained if a cache setting greater than one is used for a sequence object that will be used concurrently by multiple sessions. Then, the next cache-1 uses of NEXTVAL within that session simply return the preallocated values without touching the sequence object. So, any numbers allocated but not used within a session will be lost when that session ends, resulting in "holes" in the sequence.

Furthermore, 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, with a cache setting of 10, session A might reserve values 1 to 10 and return NEXTVAL=1, then session B might reserve values 11 to 20 and return NEXTVAL=11 before session A has generated NEXTVAL=2. Thus, with a cache setting of one it is safe to assume that NEXTVAL values are generated sequentially. With a cache setting greater than one you only assume that the NEXTVAL values are all distinct, not that they are generated purely sequentially. Also, the last value will reflect the latest value reserved by any session, whether or not it has yet been returned by NEXTVAL.

Examples

Create an ascending sequence called serial, starting at 101:

CREATE SEQUENCE serial START WITH 101;

Select the next number from this sequence:

SELECT serial.NEXTVAL FROM DUAL;


 nextval

---------

     101

(1 row)            

Create a sequence called supplier_seq with the NOCACHE option:

CREATE SEQUENCE supplier_seq
    MINVALUE 1
    START WITH 1
    INCREMENT BY 1
    NOCACHE;

Select the next number from this sequence:

SELECT supplier_seq.NEXTVAL FROM DUAL;

 nextval
---------
       1
(1 row)