5.14. SEQUENCE
(GENERATOR
)
A sequence — or generator — is a database object used to get unique number values to fill a series.
Sequence
is the SQL-compliant term for the same thing which — in Firebird — has traditionally been known as generator
.
Firebird has syntax for both terms.
Sequences are stored as 64-bit integers, regardless of the SQL dialect of the database.
If a client is connected using Dialect 1, the server handles sequence values as 32-bit integers. Passing a sequence value to a 32-bit field or variable will not cause errors as long as the current value of the sequence does not exceed the limits of a 32-bit number. However, as soon as the sequence value exceeds this limit, a database in Dialect 3 will produce an error. A database in Dialect 1 will truncate (overflow) the value, which could compromise the uniqueness of the series.
This section describes how to create, alter, set and drop sequences.
5.14.1. CREATE SEQUENCE
Used forCreating a new SEQUENCE
(GENERATOR
)
Available inDSQL, ESQL
Syntax
|
CREATE {SEQUENCE | GENERATOR} seq_name
| [START WITH start_value]
| [INCREMENT [BY] increment]
CREATE SEQUENCE
Statement ParametersParameter | Description |
---|---|
seq_name | Sequence name. The maximum length is 63 characters |
start_value | First value produced by |
increment | Increment of the sequence when using |
When a sequence is created, its current value is set so that the next value produced by NEXT VALUE FOR seq_name
is equal to start_value.
In other words, the current value of the sequence is set to (start_value - increment
).
The optional INCREMENT [BY]
clause allows you to specify a non-zero increment for the NEXT VALUE FOR seq_name
expression.
The GEN_ID(seq_name, step)
function can be called instead, to step
the sequence by a different increment.
The increment specified through INCREMENT [BY]
is not used by GEN_ID
.
Using both NEXT VALUE FOR
and GEN_ID
, especially when the sequence has an increment other than 1
, may result in values you did not expect.
For example, if you execute CREATE SEQUENCE x START WITH 10 INCREMENT BY 10
, and then use GEN_ID(x, 1)
, the value returned is 1
, and if you then call NEXT VALUE FOR x
, you get 11
.
The SQL standard specifies that sequences with a negative increment should start at the maximum value of the sequence (263 - 1) and count down.
Firebird does not do that, and instead starts at 1
unless you specify a START WITH
value.
This may change in a future Firebird version.
The statements CREATE SEQUENCE
and CREATE GENERATOR
are synonymous — both create a new sequence.
Either can be used, but CREATE SEQUENCE
is recommended as that is the syntax defined in the SQL standard.
5.14.1.1. Who Can Create a Sequence?
The CREATE SEQUENCE
(CREATE GENERATOR
) statement can be executed by:
Users with the
CREATE SEQUENCE
(CREATE GENERATOR
) privilege
The user executing CREATE SEQUENCE
(CREATE GENERATOR
) becomes its owner.
5.14.1.2. Examples of CREATE SEQUENCE
Creating the
EMP_NO_GEN
sequence usingCREATE SEQUENCE
.|
CREATE SEQUENCE EMP_NO_GEN;
Creating the
EMP_NO_GEN
sequence usingCREATE GENERATOR
.|
CREATE GENERATOR EMP_NO_GEN;
Creating the
EMP_NO_GEN
sequence with an initial value of 5 and an increment of 1.|
CREATE SEQUENCE EMP_NO_GEN START WITH 5;
Creating the
EMP_NO_GEN
sequence with an initial value of 1 and an increment of 10.|
CREATE SEQUENCE EMP_NO_GEN INCREMENT BY 10;
Creating the
EMP_NO_GEN
sequence with an initial value of 5 and an increment of 10.|
CREATE SEQUENCE EMP_NO_GEN START WITH 5 INCREMENT BY 10;
See alsoSection 5.14.2, “ALTER SEQUENCE
”, Section 5.14.3, “CREATE OR ALTER SEQUENCE
”, Section 5.14.4, “DROP SEQUENCE
”, Section 5.14.5, “RECREATE SEQUENCE
”, Section 5.14.6, “SET GENERATOR
”, NEXT VALUE FOR
, GEN_ID() function
5.14.2. ALTER SEQUENCE
Used forSetting the next value of a sequence or changing its increment
Available inDSQL
Syntax
|
ALTER {SEQUENCE | GENERATOR} seq_name
| [RESTART [WITH start_value]]
| [INCREMENT [BY] increment]
ALTER SEQUENCE
Statement ParametersParameter | Description |
---|---|
seq_name | Sequence name |
start_value | Next value produced by |
increment | Increment of the sequence (when using |
The ALTER SEQUENCE
statement sets the next value of the sequence, and/or changes the increment of the sequence.
The RESTART WITH start_value
clause sets the current value of the sequence so that the next value obtained from NEXT VALUE FOR seq_name
is equal to start_value.
To achieve this, the current value of the sequence is set to (start_value - increment
) with increment either as specified in the statement, or from the metadata of the sequence.
The RESTART
clause without WITH start_value
behaves as if WITH start_value
is specified with the start value from the metadata of the sequence.
Contrary to Firebird 3.0, since Firebird 4.0 RESTART WITH start_value
only restarts the sequence with the specified value, and does not store start_value as the new start value of the sequence.
A subsequent ALTER SEQUENCE RESTART
will use the start value specified when the sequence was created, and not the start_value of this statement.
This behaviour is specified in the SQL standard.
It is currently not possible to change the start value stored in the metadata.
Incorrect use of ALTER SEQUENCE
— changing the current value of the sequence or generator — is likely to break the logical integrity of data, or result in primary key or unique constraint violations.
INCREMENT [BY]
allows you to change the sequence increment for the NEXT VALUE FOR
expression.
Changing the increment value takes effect for all queries that run after the transaction commits.
Procedures that are called for the first time after changing the commit, will use the new value if they use NEXT VALUE FOR
.
Procedures that were already cached in the metadata cache will continue to use the old increment.
You may need to close all connections to the database for the metadata cache to clear, and the new increment to be used.
Procedures using NEXT VALUE FOR
do not need to be recompiled to see the new increment.
Procedures using GEN_ID(gen, expression)
are not affected when the increment is changed.
5.14.2.1. Who Can Alter a Sequence?
The ALTER SEQUENCE
(ALTER GENERATOR
) statement can be executed by:
The owner of the sequence
Users with the
ALTER ANY SEQUENCE
(ALTER ANY GENERATOR
) privilege
5.14.2.2. Examples of ALTER SEQUENCE
Setting the value of the
EMP_NO_GEN
sequence so the next value is 145.|
ALTER SEQUENCE EMP_NO_GEN RESTART WITH 145;
Resetting the sequence
EMP_NO_GEN
to the start value stored in the metadata|
ALTER SEQUENCE EMP_NO_GEN RESTART;
Changing the increment of sequence
EMP_NO_GEN
to 10|
ALTER SEQUENCE EMP_NO_GEN INCREMENT BY 10;
See alsoSection 5.14.6, “SET GENERATOR
”, Section 5.14.1, “CREATE SEQUENCE
”, Section 5.14.3, “CREATE OR ALTER SEQUENCE
”, Section 5.14.4, “DROP SEQUENCE
”, Section 5.14.5, “RECREATE SEQUENCE
”, NEXT VALUE FOR
, GEN_ID() function
5.14.3. CREATE OR ALTER SEQUENCE
Used forCreating a new or modifying an existing sequence
Available inDSQL, ESQL
Syntax
|
CREATE OR ALTER {SEQUENCE | GENERATOR} seq_name
| {RESTART | START WITH start_value}
| [INCREMENT [BY] increment]
CREATE OR ALTER SEQUENCE
Statement ParametersParameter | Description |
---|---|
seq_name | Sequence name. The maximum length is 63 characters |
start_value | First or next value produced by |
increment | Increment of the sequence when using |
If the sequence does not exist, it will be created as documented under Section 5.14.1, “CREATE SEQUENCE
”.
An existing sequence will be changed:
If
RESTART
is specified, the sequence is restarted with the start value stored in the metadataIf the
START WITH
clause is specified, the sequence is restarted with start_value, but the start_value is not stored. In other words, it behaves asRESTART WITH
in Section 5.14.2, “ALTER SEQUENCE
”.If the
INCREMENT [BY]
clause is specified, increment is stored as the increment in the metadata, and used for subsequent calls toNEXT VALUE FOR
5.14.3.1. Example of CREATE OR ALTER SEQUENCE
Create a new or modify an existing sequence EMP_NO_GEN
|
CREATE OR ALTER SEQUENCE EMP_NO_GEN
| START WITH 10
| INCREMENT BY 1
See alsoSection 5.14.1, “CREATE SEQUENCE
”, Section 5.14.2, “ALTER SEQUENCE
”, Section 5.14.4, “DROP SEQUENCE
”, Section 5.14.5, “RECREATE SEQUENCE
”, Section 5.14.6, “SET GENERATOR
”, NEXT VALUE FOR
, GEN_ID() function
5.14.4. DROP SEQUENCE
Used forDropping (deleting) a SEQUENCE
(GENERATOR
)
Available inDSQL, ESQL
Syntax
|
DROP {SEQUENCE | GENERATOR} seq_name
DROP SEQUENCE
Statement ParameterParameter | Description |
---|---|
seq_name | Sequence name. The maximum length is 63 characters |
The statements DROP SEQUENCE
and DROP GENERATOR
are equivalent: both drop (delete) an existing sequence.
Either is valid but DROP SEQUENCE
, being defined in the SQL standard, is recommended.
The statements will fail if the sequence has dependencies.
5.14.4.1. Who Can Drop a Sequence?
The DROP SEQUENCE
(DROP GENERATOR
) statement can be executed by:
The owner of the sequence
Users with the
DROP ANY SEQUENCE
(DROP ANY GENERATOR
) privilege
5.14.4.2. Example of DROP SEQUENCE
Dropping the EMP_NO_GEN
series:
|
DROP SEQUENCE EMP_NO_GEN;
See alsoSection 5.14.1, “CREATE SEQUENCE
”, Section 5.14.3, “CREATE OR ALTER SEQUENCE
”, Section 5.14.5, “RECREATE SEQUENCE
”
5.14.5. RECREATE SEQUENCE
Used forCreating or recreating a sequence
Available inDSQL, ESQL
Syntax
|
RECREATE {SEQUENCE | GENERATOR} seq_name
| [START WITH start_value]
| [INCREMENT [BY] increment]
RECREATE SEQUENCE
Statement ParametersParameter | Description |
---|---|
seq_name | Sequence name. The maximum length is 63 characters |
start_value | First value produced by |
increment | Increment of the sequence (when using |
See Section 5.14.1, “CREATE SEQUENCE
” for the full syntax of CREATE SEQUENCE
and descriptions of defining a sequences and its options.
RECREATE SEQUENCE
creates or recreates a sequence.
If a sequence with this name already exists, the RECREATE SEQUENCE
statement will try to drop it and create a new one.
Existing dependencies will prevent the statement from executing.
5.14.5.1. Example of RECREATE SEQUENCE
Recreating sequence EMP_NO_GEN
|
RECREATE SEQUENCE EMP_NO_GEN
| START WITH 10
| INCREMENT BY 2;
See alsoSection 5.14.1, “CREATE SEQUENCE
”, Section 5.14.2, “ALTER SEQUENCE
”, Section 5.14.3, “CREATE OR ALTER SEQUENCE
”, Section 5.14.4, “DROP SEQUENCE
”, Section 5.14.6, “SET GENERATOR
”, NEXT VALUE FOR
, GEN_ID() function
5.14.6. SET GENERATOR
Used forSetting the current value of a sequence or generator to a specified value
Available inDSQL, ESQL
Syntax
|
SET GENERATOR seq_name TO new_val
SET GENERATOR
Statement ParametersParameter | Description |
---|---|
seq_name | Sequence name |
new_val | New sequence value. A 64-bit integer from -2-63 to 263-1. |
The SET GENERATOR
statement sets the current value of a sequence or generator to the specified value.
Although SET GENERATOR
is considered outdated, it is retained for backward compatibility.
Use of the standards-compliant ALTER SEQUENCE
is recommended.
5.14.6.1. Who Can Use a SET GENERATOR
?
The SET GENERATOR
statement can be executed by:
The owner of the sequence
Users with the
ALTER ANY SEQUENCE
(ALTER ANY GENERATOR
) privilege
5.14.6.2. Example of SET GENERATOR
Setting the value of the EMP_NO_GEN
sequence to 145:
|
SET GENERATOR EMP_NO_GEN TO 145;
Similar effects can be achieved with Section 5.14.2, “ALTER SEQUENCE
”:
|ALTER SEQUENCE EMP_NO_GEN
|RESTART WITH 145 + increment;
Here, the value of increment is the current increment of the sequence.
We need add it as ALTER SEQUENCE
calculates the current value to set based on the next value it should produce.
See alsoSection 5.14.2, “ALTER SEQUENCE
”, Section 5.14.1, “CREATE SEQUENCE
”, Section 5.14.3, “CREATE OR ALTER SEQUENCE
”, Section 5.14.4, “DROP SEQUENCE
”, NEXT VALUE FOR
, GEN_ID() function