--- layout: docu railroad: statements/createsequence.js redirect_from: - /docs/sql/statements/create_sequence title: CREATE SEQUENCE Statement --- The `CREATE SEQUENCE` statement creates a new sequence number generator. ### Examples Generate an ascending sequence starting from 1: ```sql CREATE SEQUENCE serial; ``` Generate sequence from a given start number: ```sql CREATE SEQUENCE serial START 101; ``` Generate odd numbers using `INCREMENT BY`: ```sql CREATE SEQUENCE serial START WITH 1 INCREMENT BY 2; ``` Generate a descending sequence starting from 99: ```sql CREATE SEQUENCE serial START WITH 99 INCREMENT BY -1 MAXVALUE 99; ``` By default, cycles are not allowed and will result in error, e.g.: ```console Sequence Error: nextval: reached maximum value of sequence "serial" (10) ``` ```sql CREATE SEQUENCE serial START WITH 1 MAXVALUE 10; ``` `CYCLE` allows cycling through the same sequence repeatedly: ```sql CREATE SEQUENCE serial START WITH 1 MAXVALUE 10 CYCLE; ``` ### Creating and Dropping Sequences Sequences can be created and dropped similarly to other catalogue items. Overwrite an existing sequence: ```sql CREATE OR REPLACE SEQUENCE serial; ``` Only create sequence if no such sequence exists yet: ```sql CREATE SEQUENCE IF NOT EXISTS serial; ``` Remove sequence: ```sql DROP SEQUENCE serial; ``` Remove sequence if exists: ```sql DROP SEQUENCE IF EXISTS serial; ``` ### Using Sequences for Primary Keys Sequences can provide an integer primary key for a table. For example: ```sql CREATE SEQUENCE id_sequence START 1; CREATE TABLE tbl (id INTEGER DEFAULT nextval('id_sequence'), s VARCHAR); INSERT INTO tbl (s) VALUES ('hello'), ('world'); SELECT * FROM tbl; ``` The script results in the following table: | id | s | |---:|-------| | 1 | hello | | 2 | world | Sequences can also be added using the [`ALTER TABLE` statement]({% link docs/stable/sql/statements/alter_table.md %}). The following example adds an `id` column and fills it with values generated by the sequence: ```sql CREATE TABLE tbl (s VARCHAR); INSERT INTO tbl VALUES ('hello'), ('world'); CREATE SEQUENCE id_sequence START 1; ALTER TABLE tbl ADD COLUMN id INTEGER DEFAULT nextval('id_sequence'); SELECT * FROM tbl; ``` This script results in the same table as the previous example. ### Selecting the Next Value To select the next number from a sequence, use `nextval`: ```sql CREATE SEQUENCE serial START 1; SELECT nextval('serial') AS nextval; ``` | nextval | |--------:| | 1 | Using this sequence in an `INSERT` command: ```sql INSERT INTO distributors VALUES (nextval('serial'), 'nothing'); ``` ### Selecting the Current Value You may also view the current number from the sequence. Note that the `nextval` function must have already been called before calling `currval`, otherwise a Serialization Error (`sequence is not yet defined in this session`) will be thrown. ```sql CREATE SEQUENCE serial START 1; SELECT nextval('serial') AS nextval; SELECT currval('serial') AS currval; ``` | currval | |--------:| | 1 | ### Syntax <div id="rrdiagram"></div> `CREATE SEQUENCE` creates a new sequence number generator. If a schema name is given then the sequence is created in the specified schema. Otherwise it is created in the current schema. Temporary sequences exist in a special schema, so a schema name may not be given when creating a temporary sequence. The sequence name must be distinct from the name of any other sequence in the same schema. After a sequence is created, you use the function `nextval` to operate on the sequence. ## Parameters | Name | Description | |:--|:-----| | `CYCLE` or `NO 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` are specified, `NO CYCLE` is the default. | | `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. | | `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 2^63 - 1 and -1 for ascending and descending sequences, respectively. | | `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 -(2^63 - 1) for ascending and descending sequences, respectively. | | `name` | The name (optionally schema-qualified) of the sequence to be created. | | `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. | | `TEMPORARY` or `TEMP` | If specified, the sequence object is created only for this session, and is automatically dropped on session exit. Existing permanent sequences with the same name are not visible (in this session) while the temporary sequence exists, unless they are referenced with schema-qualified names. | > Sequences are based on `BIGINT` arithmetic, so the range cannot exceed the range of an eight-byte integer (-9223372036854775808 to 9223372036854775807). ## Limitations Due to limitations in DuckDB's dependency manager, `DROP SEQUENCE` will fail in some corner cases. For example, deleting a column that uses a sequence should allow the sequence to be dropped but this currently returns an error: ```sql CREATE SEQUENCE id_sequence START 1; CREATE TABLE tbl (id INTEGER DEFAULT nextval('id_sequence'), s VARCHAR); ALTER TABLE tbl DROP COLUMN id; DROP SEQUENCE id_sequence; ``` ```console Dependency Error: Cannot drop entry "id_sequence" because there are entries that depend on it. table "tbl" depends on index "id_sequence". Use DROP...CASCADE to drop all dependents. ``` This can be worked around by using the `CASCADE` modifier. The following command drops the sequence: ```sql DROP SEQUENCE id_sequence CASCADE; ```