1CREATE SEQUENCE(7)       PostgreSQL 11.3 Documentation      CREATE SEQUENCE(7)
2
3
4

NAME

6       CREATE_SEQUENCE - define a new sequence generator
7

SYNOPSIS

9       CREATE [ TEMPORARY | TEMP ] SEQUENCE [ IF NOT EXISTS ] name
10           [ AS data_type ]
11           [ INCREMENT [ BY ] increment ]
12           [ MINVALUE minvalue | NO MINVALUE ] [ MAXVALUE maxvalue | NO MAXVALUE ]
13           [ START [ WITH ] start ] [ CACHE cache ] [ [ NO ] CYCLE ]
14           [ OWNED BY { table_name.column_name | NONE } ]
15

DESCRIPTION

17       CREATE SEQUENCE creates a new sequence number generator. This involves
18       creating and initializing a new special single-row table with the name
19       name. The generator will be owned by the user issuing the command.
20
21       If a schema name is given then the sequence is created in the specified
22       schema. Otherwise it is created in the current schema. Temporary
23       sequences exist in a special schema, so a schema name cannot be given
24       when creating a temporary sequence. The sequence name must be distinct
25       from the name of any other sequence, table, index, view, or foreign
26       table in the same schema.
27
28       After a sequence is created, you use the functions nextval, currval,
29       and setval to operate on the sequence. These functions are documented
30       in Section 9.16.
31
32       Although you cannot update a sequence directly, you can use a query
33       like:
34
35           SELECT * FROM name;
36
37       to examine the parameters and current state of a sequence. In
38       particular, the last_value field of the sequence shows the last value
39       allocated by any session. (Of course, this value might be obsolete by
40       the time it's printed, if other sessions are actively doing nextval
41       calls.)
42

PARAMETERS

44       TEMPORARY or TEMP
45           If specified, the sequence object is created only for this session,
46           and is automatically dropped on session exit. Existing permanent
47           sequences with the same name are not visible (in this session)
48           while the temporary sequence exists, unless they are referenced
49           with schema-qualified names.
50
51       IF NOT EXISTS
52           Do not throw an error if a relation with the same name already
53           exists. A notice is issued in this case. Note that there is no
54           guarantee that the existing relation is anything like the sequence
55           that would have been created - it might not even be a sequence.
56
57       name
58           The name (optionally schema-qualified) of the sequence to be
59           created.
60
61       data_type
62           The optional clause AS data_type specifies the data type of the
63           sequence. Valid types are smallint, integer, and bigint.  bigint is
64           the default. The data type determines the default minimum and
65           maximum values of the sequence.
66
67       increment
68           The optional clause INCREMENT BY increment specifies which value is
69           added to the current sequence value to create a new value. A
70           positive value will make an ascending sequence, a negative one a
71           descending sequence. The default value is 1.
72
73       minvalue
74       NO MINVALUE
75           The optional clause MINVALUE minvalue determines the minimum value
76           a sequence can generate. If this clause is not supplied or NO
77           MINVALUE is specified, then defaults will be used. The default for
78           an ascending sequence is 1. The default for a descending sequence
79           is the minimum value of the data type.
80
81       maxvalue
82       NO MAXVALUE
83           The optional clause MAXVALUE maxvalue determines the maximum value
84           for the sequence. If this clause is not supplied or NO MAXVALUE is
85           specified, then default values will be used. The default for an
86           ascending sequence is the maximum value of the data type. The
87           default for a descending sequence is -1.
88
89       start
90           The optional clause START WITH start allows the sequence to begin
91           anywhere. The default starting value is minvalue for ascending
92           sequences and maxvalue for descending ones.
93
94       cache
95           The optional clause CACHE cache specifies how many sequence numbers
96           are to be preallocated and stored in memory for faster access. The
97           minimum value is 1 (only one value can be generated at a time,
98           i.e., no cache), and this is also the default.
99
100       CYCLE
101       NO CYCLE
102           The CYCLE option allows the sequence to wrap around when the
103           maxvalue or minvalue has been reached by an ascending or descending
104           sequence respectively. If the limit is reached, the next number
105           generated will be the minvalue or maxvalue, respectively.
106
107           If NO CYCLE is specified, any calls to nextval after the sequence
108           has reached its maximum value will return an error. If neither
109           CYCLE or NO CYCLE are specified, NO CYCLE is the default.
110
111       OWNED BY table_name.column_name
112       OWNED BY NONE
113           The OWNED BY option causes the sequence to be associated with a
114           specific table column, such that if that column (or its whole
115           table) is dropped, the sequence will be automatically dropped as
116           well. The specified table must have the same owner and be in the
117           same schema as the sequence.  OWNED BY NONE, the default, specifies
118           that there is no such association.
119

NOTES

121       Use DROP SEQUENCE to remove a sequence.
122
123       Sequences are based on bigint arithmetic, so the range cannot exceed
124       the range of an eight-byte integer (-9223372036854775808 to
125       9223372036854775807).
126
127       Because nextval and setval calls are never rolled back, sequence
128       objects cannot be used if “gapless” assignment of sequence numbers is
129       needed. It is possible to build gapless assignment by using exclusive
130       locking of a table containing a counter; but this solution is much more
131       expensive than sequence objects, especially if many transactions need
132       sequence numbers concurrently.
133
134       Unexpected results might be obtained if a cache setting greater than
135       one is used for a sequence object that will be used concurrently by
136       multiple sessions. Each session will allocate and cache successive
137       sequence values during one access to the sequence object and increase
138       the sequence object's last_value accordingly. Then, the next cache-1
139       uses of nextval within that session simply return the preallocated
140       values without touching the sequence object. So, any numbers allocated
141       but not used within a session will be lost when that session ends,
142       resulting in “holes” in the sequence.
143
144       Furthermore, although multiple sessions are guaranteed to allocate
145       distinct sequence values, the values might be generated out of sequence
146       when all the sessions are considered. For example, with a cache setting
147       of 10, session A might reserve values 1..10 and return nextval=1, then
148       session B might reserve values 11..20 and return nextval=11 before
149       session A has generated nextval=2. Thus, with a cache setting of one it
150       is safe to assume that nextval values are generated sequentially; with
151       a cache setting greater than one you should only assume that the
152       nextval values are all distinct, not that they are generated purely
153       sequentially. Also, last_value will reflect the latest value reserved
154       by any session, whether or not it has yet been returned by nextval.
155
156       Another consideration is that a setval executed on such a sequence will
157       not be noticed by other sessions until they have used up any
158       preallocated values they have cached.
159

EXAMPLES

161       Create an ascending sequence called serial, starting at 101:
162
163           CREATE SEQUENCE serial START 101;
164
165       Select the next number from this sequence:
166
167           SELECT nextval('serial');
168
169            nextval
170           ---------
171                101
172
173       Select the next number from this sequence:
174
175           SELECT nextval('serial');
176
177            nextval
178           ---------
179                102
180
181       Use this sequence in an INSERT command:
182
183           INSERT INTO distributors VALUES (nextval('serial'), 'nothing');
184
185       Update the sequence value after a COPY FROM:
186
187           BEGIN;
188           COPY distributors FROM 'input_file';
189           SELECT setval('serial', max(id)) FROM distributors;
190           END;
191

COMPATIBILITY

193       CREATE SEQUENCE conforms to the SQL standard, with the following
194       exceptions:
195
196       ·   Obtaining the next value is done using the nextval() function
197           instead of the standard's NEXT VALUE FOR expression.
198
199       ·   The OWNED BY clause is a PostgreSQL extension.
200

SEE ALSO

202       ALTER SEQUENCE (ALTER_SEQUENCE(7)), DROP SEQUENCE (DROP_SEQUENCE(7))
203
204
205
206PostgreSQL 11.3                      2019                   CREATE SEQUENCE(7)
Impressum