Switch to: V14V13V12V11V10V9V8V7V6V5

CREATE SEQUENCE

Defines a new sequence.

Syntax

sequence_definition
    :    CREATE [TEMPORARY] SEQUENCE sequence_name
         [ INCREMENT [BY] increment ]
         [ MINVALUE minvalue | NO MINVALUE ] 
         [ MAXVALUE maxvalue | NO MAXVALUE ]
         [ START [WITH] start ] 
         [ [NO] CYCLE ]

ARGUMENTS

TEMPORARY

If specified, the sequence object is created only for this session and is automatically dropped on the session exit.

sequence_name

The name of the sequence to be created.

increment

The optional clause INCREMENT BY increment specifies which value is added 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.

minvalue

The optional clause 'MINVALUE minvalue' determines the minimum value a sequence can generate. If this clause is not supplied or NO MINVALUE is specified, then defaults will be used. The defaults are 1 and -263-1 for ascending and descending sequences, respectively.

maxvalue

The optional clause 'MAXVALUE maxvalue' determines the maximum value for the sequence. If this clause is not supplied or NO MAXVALUE is specified, then default values will be used. The defaults are 263-1 and -1 for ascending and descending sequences, respectively.

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.

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 NO CYCLE is specified, any calls to nextval after the sequence has reached its maximum value will return an error. If neither CYCLE or NO CYCLE is specified, NO CYCLE is the default.

Description

Sequences were added into Valentina Database v5.0 to have more compatibility with PostgreSQL, Oracle, and even SQL Standard. But please note that if PostgreSQL requires a tool to generate synthetic PK values for Valentina DB this is one of the alternatives:

  • Valentina also has an auto-increment flag similar to MySQL. It is a simpler way, but less control over values and behavior of generated values.
  • Valentina Tables have a RecID field, which in most cases eliminates the need for Primary Key fields at all. This is the recommended way for Valentina DB developers.

Sequences are based on bigint arithmetic, so the range cannot exceed the range of an eight-byte integer (-9223372036854775808 to 9223372036854775807).

Please note, that the sequence is a helper object to get some new value only - it is not a constraint itself. This value is defined by sequence setting like “first value”, “step” … and “cycled” (so the sequence may produce not a unique set of values, but “cycled”). The sequence can be used as a source to prepare the value for PK/Unique field (but not a “cycled” sequence).

Sequence's purpose is just to generate some new value - nothing more.

If you have N tables with N Primary Keys and you want to use sequences to generate values, then you will need to create N sequences in the database using the CREATE SEQUENCE command. To remove a sequence use the DROP SEQUENCE command. Another way is to use SERIAL32 or SERIAL64 serial types. In most cases, you can use default values to create a sequence. This will start value from 1 and increment by 1. To obtain the next value from the sequence you should use the function nextVal(). For advanced control over sequence, you can use yet setVal(), and currVal() functions.

See also Sequence Manipulation Functions, Serial Types

Examples

Create an ascending sequence called seqPersonID, starting at 101:

CREATE SEQUENCE seqPersonID START 101;

Select the next number for the sequence:

SELECT NEXTVAL('seqPersonID');
 
 NEXTVAL
---------
     101

Use the sequence in the INSERT command:

INSERT INTO tblPerson( fldID, fldFirstName, fldLastName ) 
               VALUES( NEXTVAL('seqPersonID'), 'Peter', 'Peterson' );

Update the sequence value after a COPY FROM:

BEGIN;
COPY distributors FROM 'input_file';
 
SET max_id = SELECT MAX(id) FROM distributors;
SELECT SETVAL('serial', @max_id);
END;

You can use currVal() to assign the Foreign Key value of T2 to just inserted PK of T1.

INSERT INTO tblPerson( fldID, fldFirstName, fldLastName ) 
               VALUES( NEXTVAL('seqPersonID'), 'Peter', 'Peterson' );
 
INSERT INTO tblPhone( fldID, fldNumber, fldPersonPtr ) 
              VALUES( NEXTVAL('seqPhoneID'), '1111111', currval('seqPersonID') ); 

Or you can use a Variable to get the same result:

SET gPersonID = NEXTVAL('seqPersonID');
 
INSERT INTO tblPerson( fldID, fldFirstName, fldLastName ) 
               VALUES( @gPersonID, 'Peter', 'Peterson' );
 
INSERT INTO tblPhone( fldID, fldNumber, fldPersonPtr ) 
              VALUES( NEXTVAL('seqPhoneID'), '1111111', @gPersonID ); 

See Also

Check SERIAL32 and SERIAL64 pseudo-types for columns as a more simple construction to be used in most cases.

Compatibility

CREATE SEQUENCE conforms to the SQL standard, with the following exceptions:

  • The standard's AS <data type> expression is not supported.
  • Obtaining the next value is done using the nextval() function instead of the standard's NEXT VALUE FOR expression.