1CREATE SEQUENCE(7) PostgreSQL 15.4 Documentation CREATE SEQUENCE(7)
2
3
4
6 CREATE_SEQUENCE - define a new sequence generator
7
9 CREATE [ { TEMPORARY | TEMP } | UNLOGGED ] 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
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 relation (table, sequence, index, view,
26 materialized view, or foreign 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.17.
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
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 UNLOGGED
52 If specified, the sequence is created as an unlogged sequence.
53 Changes to unlogged sequences are not written to the write-ahead
54 log. They are not crash-safe: an unlogged sequence is automatically
55 reset to its initial state after a crash or unclean shutdown.
56 Unlogged sequences are also not replicated to standby servers.
57
58 Unlike unlogged tables, unlogged sequences do not offer a
59 significant performance advantage. This option is mainly intended
60 for sequences associated with unlogged tables via identity columns
61 or serial columns. In those cases, it usually wouldn't make sense
62 to have the sequence WAL-logged and replicated but not its
63 associated table.
64
65 IF NOT EXISTS
66 Do not throw an error if a relation with the same name already
67 exists. A notice is issued in this case. Note that there is no
68 guarantee that the existing relation is anything like the sequence
69 that would have been created — it might not even be a sequence.
70
71 name
72 The name (optionally schema-qualified) of the sequence to be
73 created.
74
75 data_type
76 The optional clause AS data_type specifies the data type of the
77 sequence. Valid types are smallint, integer, and bigint. bigint is
78 the default. The data type determines the default minimum and
79 maximum values of the sequence.
80
81 increment
82 The optional clause INCREMENT BY increment specifies which value is
83 added to the current sequence value to create a new value. A
84 positive value will make an ascending sequence, a negative one a
85 descending sequence. The default value is 1.
86
87 minvalue
88 NO MINVALUE
89 The optional clause MINVALUE minvalue determines the minimum value
90 a sequence can generate. If this clause is not supplied or NO
91 MINVALUE is specified, then defaults will be used. The default for
92 an ascending sequence is 1. The default for a descending sequence
93 is the minimum value of the data type.
94
95 maxvalue
96 NO MAXVALUE
97 The optional clause MAXVALUE maxvalue determines the maximum value
98 for the sequence. If this clause is not supplied or NO MAXVALUE is
99 specified, then default values will be used. The default for an
100 ascending sequence is the maximum value of the data type. The
101 default for a descending sequence is -1.
102
103 start
104 The optional clause START WITH start allows the sequence to begin
105 anywhere. The default starting value is minvalue for ascending
106 sequences and maxvalue for descending ones.
107
108 cache
109 The optional clause CACHE cache specifies how many sequence numbers
110 are to be preallocated and stored in memory for faster access. The
111 minimum value is 1 (only one value can be generated at a time,
112 i.e., no cache), and this is also the default.
113
114 CYCLE
115 NO CYCLE
116 The CYCLE option allows the sequence to wrap around when the
117 maxvalue or minvalue has been reached by an ascending or descending
118 sequence respectively. If the limit is reached, the next number
119 generated will be the minvalue or maxvalue, respectively.
120
121 If NO CYCLE is specified, any calls to nextval after the sequence
122 has reached its maximum value will return an error. If neither
123 CYCLE or NO CYCLE are specified, NO CYCLE is the default.
124
125 OWNED BY table_name.column_name
126 OWNED BY NONE
127 The OWNED BY option causes the sequence to be associated with a
128 specific table column, such that if that column (or its whole
129 table) is dropped, the sequence will be automatically dropped as
130 well. The specified table must have the same owner and be in the
131 same schema as the sequence. OWNED BY NONE, the default, specifies
132 that there is no such association.
133
135 Use DROP SEQUENCE to remove a sequence.
136
137 Sequences are based on bigint arithmetic, so the range cannot exceed
138 the range of an eight-byte integer (-9223372036854775808 to
139 9223372036854775807).
140
141 Because nextval and setval calls are never rolled back, sequence
142 objects cannot be used if “gapless” assignment of sequence numbers is
143 needed. It is possible to build gapless assignment by using exclusive
144 locking of a table containing a counter; but this solution is much more
145 expensive than sequence objects, especially if many transactions need
146 sequence numbers concurrently.
147
148 Unexpected results might be obtained if a cache setting greater than
149 one is used for a sequence object that will be used concurrently by
150 multiple sessions. Each session will allocate and cache successive
151 sequence values during one access to the sequence object and increase
152 the sequence object's last_value accordingly. Then, the next cache-1
153 uses of nextval within that session simply return the preallocated
154 values without touching the sequence object. So, any numbers allocated
155 but not used within a session will be lost when that session ends,
156 resulting in “holes” in the sequence.
157
158 Furthermore, although multiple sessions are guaranteed to allocate
159 distinct sequence values, the values might be generated out of sequence
160 when all the sessions are considered. For example, with a cache setting
161 of 10, session A might reserve values 1..10 and return nextval=1, then
162 session B might reserve values 11..20 and return nextval=11 before
163 session A has generated nextval=2. Thus, with a cache setting of one it
164 is safe to assume that nextval values are generated sequentially; with
165 a cache setting greater than one you should only assume that the
166 nextval values are all distinct, not that they are generated purely
167 sequentially. Also, last_value will reflect the latest value reserved
168 by any session, whether or not it has yet been returned by nextval.
169
170 Another consideration is that a setval executed on such a sequence will
171 not be noticed by other sessions until they have used up any
172 preallocated values they have cached.
173
175 Create an ascending sequence called serial, starting at 101:
176
177 CREATE SEQUENCE serial START 101;
178
179 Select the next number from this sequence:
180
181 SELECT nextval('serial');
182
183 nextval
184 ---------
185 101
186
187 Select the next number from this sequence:
188
189 SELECT nextval('serial');
190
191 nextval
192 ---------
193 102
194
195 Use this sequence in an INSERT command:
196
197 INSERT INTO distributors VALUES (nextval('serial'), 'nothing');
198
199 Update the sequence value after a COPY FROM:
200
201 BEGIN;
202 COPY distributors FROM 'input_file';
203 SELECT setval('serial', max(id)) FROM distributors;
204 END;
205
207 CREATE SEQUENCE conforms to the SQL standard, with the following
208 exceptions:
209
210 • Obtaining the next value is done using the nextval() function
211 instead of the standard's NEXT VALUE FOR expression.
212
213 • The OWNED BY clause is a PostgreSQL extension.
214
216 ALTER SEQUENCE (ALTER_SEQUENCE(7)), DROP SEQUENCE (DROP_SEQUENCE(7))
217
218
219
220PostgreSQL 15.4 2023 CREATE SEQUENCE(7)