ALTER SEQUENCE
MariaDB starting with 10.3.1
ALTER SEQUENCE is being introduced in MariaDB 10.3. Details may still change before 10.3 is released as beta.
Syntax
ALTER SEQUENCE [IF EXISTS] sequence_name [ INCREMENT [ BY | = ] increment ] [ MINVALUE [=] minvalue | NO MINVALUE | NOMINVALUE ] [ MAXVALUE [=] maxvalue | NO MAXVALUE | NOMAXVALUE ] [ START [ WITH | = ] start ] [ CACHE [=] cache ] [ [ NO ] CYCLE ] [ RESTART [[WITH | =] restart]
ALTER SEQUENCE
allows one to change any values for a SEQUENCE
created with CREATE SEQUENCE.
Description
ALTER SEQUENCE
changes the parameters of an existing sequence generator. Any parameters not specifically set in the ALTER SEQUENCE
command retain their prior settings.
Arguments to ALTER SEQUENCE
The following options may be used:
Option | Default value | Description |
---|---|---|
INCREMENT | 1 | Increment to use for values. May be negative. |
MINVALUE | 1 if INCREMENT > 0 and -9223372036854775807 if INCREMENT < 0 | Minimum value for the sequence. |
MAXVALUE | 9223372036854775806 if INCREMENT > 0 and -1 if INCREMENT < 0 | Max value for sequence. |
START | MINVALUE if INCREMENT > 0 and MAX_VALUE if INCREMENT< 0 | First value that the sequence will generate. |
CACHE | 1000 | Number of values that should be cached. 0 if no CACHE. The underlying table will be updated first time a new sequence number is generated and each time the cache runs out. |
CYCLE | 0 (= NO CYCLE) | 1 if the sequence should start again from MINVAL after it has run out of values. |
RESTART | START if restart value is given | If restart is used, NEXT VALUE will return the restart value. |
The optional clause RESTART [ WITH restart ]
sets the next value for the sequence. This is equivalent to calling the SETVAL() function with the is_used
argument as 0. The specified value will be returned by the next call of nextval. Using RESTART
with no restart value is
equivalent to supplying the start value that was recorded by
CREATE SEQUENCE or last set by ALTER SEQUENCE START WITH
.
ALTER SEQUENCE
will not all you to change the sequence so that it's inconsistent. For example:
MariaDB [test]> create sequence t1; MariaDB [test]> alter sequence t1 minvalue 10; ERROR 4061 (HY000): Sequence 'test.t1' values are conflicting MariaDB [test]> alter sequence t1 minvalue 10 restart 10; ERROR 4061 (HY000): Sequence 'test.t1' values are conflicting MariaDB [test]> alter sequence t1 minvalue 10 start 10 restart 10;
INSERT
To allow SEQUENCE
objects to be backed up by old tools, like mysqldump, one can use SELECT
to read the current state of a SEQUENCE
object and use an INSERT
to update the SEQUENCE
object. INSERT
is only allowed if all fields are specified:
MariaDB [test]> create sequence t1; MariaDB [test]> insert into s1 values(1000,10,2000,1005,1,1000,0,0); MariaDB [test]> select * from s1; +------------+-----------+-----------+-------+-----------+-------+-------+-------+ | next_value | min_value | max_value | start | increment | cache | cycle | round | +------------+-----------+-----------+-------+-----------+-------+-------+-------+ | 1000 | 10 | 2000 | 1005 | 1 | 1000 | 0 | 0 | +------------+-----------+-----------+-------+-----------+-------+-------+-------+ MariaDB [test]> show create sequence s1; +-------+--------------------------------------------------------------------------------------------------------------+ | Table | Create Table | +-------+--------------------------------------------------------------------------------------------------------------+ | s1 | CREATE SEQUENCE `s1` start with 1005 minvalue 10 maxvalue 2000 increment by 1 cache 1000 nocycle ENGINE=Aria | +-------+--------------------------------------------------------------------------------------------------------------+
Notes
ALTER SEQUENCE
will take a full table lock of the sequence object during
its (brief) operation. This ensures that ALTER SEQUENCE
is replicated
correctly. If you only want to set the next sequence value to a
higher value than current, then you should use SETVAL()
instead, as this is not blocking.
If you want to change storage engine, sequence comment or rename the sequence, you can use ALTER TABLE for this.