1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
|
<!--
doc/src/sgml/ref/create_sequence.sgml
PostgreSQL documentation
-->
<refentry id="sql-createsequence">
<indexterm zone="sql-createsequence">
<primary>CREATE SEQUENCE</primary>
</indexterm>
<refmeta>
<refentrytitle>CREATE SEQUENCE</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>CREATE SEQUENCE</refname>
<refpurpose>define a new sequence generator</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
CREATE [ { TEMPORARY | TEMP } | UNLOGGED ] SEQUENCE [ IF NOT EXISTS ] <replaceable class="parameter">name</replaceable>
[ AS <replaceable class="parameter">data_type</replaceable> ]
[ INCREMENT [ BY ] <replaceable class="parameter">increment</replaceable> ]
[ MINVALUE <replaceable class="parameter">minvalue</replaceable> | NO MINVALUE ] [ MAXVALUE <replaceable class="parameter">maxvalue</replaceable> | NO MAXVALUE ]
[ START [ WITH ] <replaceable class="parameter">start</replaceable> ] [ CACHE <replaceable class="parameter">cache</replaceable> ] [ [ NO ] CYCLE ]
[ OWNED BY { <replaceable class="parameter">table_name</replaceable>.<replaceable class="parameter">column_name</replaceable> | NONE } ]
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>CREATE SEQUENCE</command> creates a new sequence number
generator. This involves creating and initializing a new special
single-row table with the name <replaceable
class="parameter">name</replaceable>. The generator will be
owned by the user issuing the command.
</para>
<para>
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 cannot be
given when creating a temporary sequence.
The sequence name must be distinct from the name of any other relation
(table, sequence, index, view, materialized view, or foreign table) in
the same schema.
</para>
<para>
After a sequence is created, you use the functions
<function>nextval</function>,
<function>currval</function>, and
<function>setval</function>
to operate on the sequence. These functions are documented in
<xref linkend="functions-sequence"/>.
</para>
<para>
Although you cannot update a sequence directly, you can use a query like:
<programlisting>
SELECT * FROM <replaceable>name</replaceable>;
</programlisting>
to examine the parameters and current state of a sequence. In particular,
the <literal>last_value</literal> field of the sequence shows the last value
allocated by any session. (Of course, this value might be obsolete
by the time it's printed, if other sessions are actively doing
<function>nextval</function> calls.)
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><literal>TEMPORARY</literal> or <literal>TEMP</literal></term>
<listitem>
<para>
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.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>UNLOGGED</literal></term>
<listitem>
<para>
If specified, the sequence is created as an unlogged sequence. Changes
to unlogged sequences are not written to the write-ahead log. They are
not crash-safe: an unlogged sequence is automatically reset to its
initial state after a crash or unclean shutdown. Unlogged sequences are
also not replicated to standby servers.
</para>
<para>
Unlike unlogged tables, unlogged sequences do not offer a significant
performance advantage. This option is mainly intended for sequences
associated with unlogged tables via identity columns or serial columns.
In those cases, it usually wouldn't make sense to have the sequence
WAL-logged and replicated but not its associated table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
<para>
Do not throw an error if a relation with the same name already exists.
A notice is issued in this case. Note that there is no guarantee that
the existing relation is anything like the sequence that would have
been created — it might not even be a sequence.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">name</replaceable></term>
<listitem>
<para>
The name (optionally schema-qualified) of the sequence to be created.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">data_type</replaceable></term>
<listitem>
<para>
The optional
clause <literal>AS <replaceable class="parameter">data_type</replaceable></literal>
specifies the data type of the sequence. Valid types are
<literal>smallint</literal>, <literal>integer</literal>,
and <literal>bigint</literal>. <literal>bigint</literal> is the
default. The data type determines the default minimum and maximum
values of the sequence.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">increment</replaceable></term>
<listitem>
<para>
The optional clause <literal>INCREMENT BY <replaceable
class="parameter">increment</replaceable></literal> 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.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">minvalue</replaceable></term>
<term><literal>NO MINVALUE</literal></term>
<listitem>
<para>
The optional clause <literal>MINVALUE <replaceable
class="parameter">minvalue</replaceable></literal> determines
the minimum value a sequence can generate. If this clause is not
supplied or <option>NO MINVALUE</option> is specified, then
defaults will be used. The default for an ascending sequence is 1. The
default for a descending sequence is the minimum value of the data type.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">maxvalue</replaceable></term>
<term><literal>NO MAXVALUE</literal></term>
<listitem>
<para>
The optional clause <literal>MAXVALUE <replaceable
class="parameter">maxvalue</replaceable></literal> determines
the maximum value for the sequence. If this clause is not
supplied or <option>NO MAXVALUE</option> is specified, then
default values will be used. The default for an ascending sequence is
the maximum value of the data type. The default for a descending
sequence is -1.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">start</replaceable></term>
<listitem>
<para>
The optional clause <literal>START WITH <replaceable
class="parameter">start</replaceable> </literal> allows the
sequence to begin anywhere. The default starting value is
<replaceable class="parameter">minvalue</replaceable> for
ascending sequences and <replaceable
class="parameter">maxvalue</replaceable> for descending ones.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">cache</replaceable></term>
<listitem>
<para>
The optional clause <literal>CACHE <replaceable
class="parameter">cache</replaceable></literal> specifies how
many sequence numbers are to be preallocated and stored in
memory for faster access. The minimum value is 1 (only one value
can be generated at a time, i.e., no cache), and this is also the
default.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CYCLE</literal></term>
<term><literal>NO CYCLE</literal></term>
<listitem>
<para>
The <literal>CYCLE</literal> option allows the sequence to wrap
around when the <replaceable
class="parameter">maxvalue</replaceable> or <replaceable
class="parameter">minvalue</replaceable> has been reached by an
ascending or descending sequence respectively. If the limit is
reached, the next number generated will be the <replaceable
class="parameter">minvalue</replaceable> or <replaceable
class="parameter">maxvalue</replaceable>, respectively.
</para>
<para>
If <literal>NO CYCLE</literal> is specified, any calls to
<function>nextval</function> after the sequence has reached its
maximum value will return an error. If neither
<literal>CYCLE</literal> or <literal>NO CYCLE</literal> are
specified, <literal>NO CYCLE</literal> is the default.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>OWNED BY</literal> <replaceable class="parameter">table_name</replaceable>.<replaceable class="parameter">column_name</replaceable></term>
<term><literal>OWNED BY NONE</literal></term>
<listitem>
<para>
The <literal>OWNED BY</literal> option causes the sequence to be
associated with a specific table column, such that if that column
(or its whole table) is dropped, the sequence will be automatically
dropped as well. The specified table must have the same owner and be in
the same schema as the sequence.
<literal>OWNED BY NONE</literal>, the default, specifies that there
is no such association.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
Use <command>DROP SEQUENCE</command> to remove a sequence.
</para>
<para>
Sequences are based on <type>bigint</type> arithmetic, so the range
cannot exceed the range of an eight-byte integer
(-9223372036854775808 to 9223372036854775807).
</para>
<para>
Because <function>nextval</function> and <function>setval</function> calls are never
rolled back, sequence objects cannot be used if <quote>gapless</quote>
assignment of sequence numbers is needed. It is possible to build
gapless assignment by using exclusive locking of a table containing a
counter; but this solution is much more expensive than sequence
objects, especially if many transactions need sequence numbers
concurrently.
</para>
<para>
Unexpected results might be obtained if a <replaceable
class="parameter">cache</replaceable> setting greater than one is
used for a sequence object that will be used concurrently by
multiple sessions. Each session will allocate and cache successive
sequence values during one access to the sequence object and
increase the sequence object's <literal>last_value</literal> accordingly.
Then, the next <replaceable class="parameter">cache</replaceable>-1
uses of <function>nextval</function> within that session simply return the
preallocated values without touching the sequence object. So, any
numbers allocated but not used within a session will be lost when
that session ends, resulting in <quote>holes</quote> in the
sequence.
</para>
<para>
Furthermore, although multiple sessions are guaranteed to allocate
distinct sequence values, the values might be generated out of
sequence when all the sessions are considered. For example, with
a <replaceable class="parameter">cache</replaceable> setting of 10,
session A might reserve values 1..10 and return
<function>nextval</function>=1, then session B might reserve values
11..20 and return <function>nextval</function>=11 before session A
has generated <function>nextval</function>=2. Thus, with a
<replaceable class="parameter">cache</replaceable> setting of one
it is safe to assume that <function>nextval</function> values are generated
sequentially; with a <replaceable
class="parameter">cache</replaceable> setting greater than one you
should only assume that the <function>nextval</function> values are all
distinct, not that they are generated purely sequentially. Also,
<literal>last_value</literal> will reflect the latest value reserved by
any session, whether or not it has yet been returned by
<function>nextval</function>.
</para>
<para>
Another consideration is that a <function>setval</function> executed on
such a sequence will not be noticed by other sessions until they
have used up any preallocated values they have cached.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
Create an ascending sequence called <literal>serial</literal>, starting at 101:
<programlisting>
CREATE SEQUENCE serial START 101;
</programlisting>
</para>
<para>
Select the next number from this sequence:
<programlisting>
SELECT nextval('serial');
nextval
---------
101
</programlisting>
</para>
<para>
Select the next number from this sequence:
<programlisting>
SELECT nextval('serial');
nextval
---------
102
</programlisting>
</para>
<para>
Use this sequence in an <command>INSERT</command> command:
<programlisting>
INSERT INTO distributors VALUES (nextval('serial'), 'nothing');
</programlisting>
</para>
<para>
Update the sequence value after a <command>COPY FROM</command>:
<programlisting>
BEGIN;
COPY distributors FROM 'input_file';
SELECT setval('serial', max(id)) FROM distributors;
END;
</programlisting></para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
<command>CREATE SEQUENCE</command> conforms to the <acronym>SQL</acronym>
standard, with the following exceptions:
<itemizedlist>
<listitem>
<para>
Obtaining the next value is done using the <function>nextval()</function>
function instead of the standard's <command>NEXT VALUE FOR</command>
expression.
</para>
</listitem>
<listitem>
<para>
The <literal>OWNED BY</literal> clause is a <productname>PostgreSQL</productname>
extension.
</para>
</listitem>
</itemizedlist></para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-altersequence"/></member>
<member><xref linkend="sql-dropsequence"/></member>
</simplelist>
</refsect1>
</refentry>
|