ALTER SEQUENCE
Sets the next value of a sequence, or changes its increment
DSQL
ALTER {SEQUENCE | GENERATOR} seq_name [RESTART [WITH newvalue]] [INCREMENT [BY] increment]
Parameter | Description |
---|---|
seq_name |
Sequence (generator) name |
newvalue |
New sequence (generator) value.A 64-bit integer from -2-63 to 263-1. |
increment |
Increment of the sequence (when using |
The ALTER SEQUENCE
statement sets the current value of a sequence to the specified valueand/or changes the increment of the sequence.
The RESTART WITH newvalue
clause allows you to set the next value generated by NEXT VALUE FOR seq_name
.To achieve this, the current value of the sequence is set to (newvalue - increment
) with increment either as specified in the statement, or stored in the metadata of the sequence.The RESTART
clause (without WITH
) restarts the sequence with the initial value stored in the metadata of the sequence.
Note
|
Contrary to Firebird 3.0, since Firebird 4.0 It is currently not possible to change the initial value stored in the metadata. |
Warning
|
Incorrect use of the |
INCREMENT [BY]
allows you to change the sequence increment for the NEXT VALUE FOR
expression.
Note
|
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 |