1CREATE SEQUENCE(7) PostgreSQL 9.2.24 Documentation CREATE SEQUENCE(7)
2
3
4
6 CREATE_SEQUENCE - define a new sequence generator
7
9 CREATE [ TEMPORARY | TEMP ] SEQUENCE name [ INCREMENT [ BY ] increment ]
10 [ MINVALUE minvalue | NO MINVALUE ] [ MAXVALUE maxvalue | NO MAXVALUE ]
11 [ START [ WITH ] start ] [ CACHE cache ] [ [ NO ] CYCLE ]
12 [ OWNED BY { table_name.column_name | NONE } ]
13
15 CREATE SEQUENCE creates a new sequence number generator. This involves
16 creating and initializing a new special single-row table with the name
17 name. The generator will be owned by the user issuing the command.
18
19 If a schema name is given then the sequence is created in the specified
20 schema. Otherwise it is created in the current schema. Temporary
21 sequences exist in a special schema, so a schema name cannot be given
22 when creating a temporary sequence. The sequence name must be distinct
23 from the name of any other sequence, table, index, view, or foreign
24 table in the same schema.
25
26 After a sequence is created, you use the functions nextval, currval,
27 and setval to operate on the sequence. These functions are documented
28 in Section 9.16, “Sequence Manipulation Functions”, in the
29 documentation.
30
31 Although you cannot update a sequence directly, you can use a query
32 like:
33
34 SELECT * FROM name;
35
36 to examine the parameters and current state of a sequence. In
37 particular, the last_value field of the sequence shows the last value
38 allocated by any session. (Of course, this value might be obsolete by
39 the time it's printed, if other sessions are actively doing nextval
40 calls.)
41
43 TEMPORARY or TEMP
44 If specified, the sequence object is created only for this session,
45 and is automatically dropped on session exit. Existing permanent
46 sequences with the same name are not visible (in this session)
47 while the temporary sequence exists, unless they are referenced
48 with schema-qualified names.
49
50 name
51 The name (optionally schema-qualified) of the sequence to be
52 created.
53
54 increment
55 The optional clause INCREMENT BY increment specifies which value is
56 added to the current sequence value to create a new value. A
57 positive value will make an ascending sequence, a negative one a
58 descending sequence. The default value is 1.
59
60 minvalue, NO MINVALUE
61 The optional clause MINVALUE minvalue determines the minimum value
62 a sequence can generate. If this clause is not supplied or NO
63 MINVALUE is specified, then defaults will be used. The defaults are
64 1 and -263-1 for ascending and descending sequences, respectively.
65
66 maxvalue, NO MAXVALUE
67 The optional clause MAXVALUE maxvalue determines the maximum value
68 for the sequence. If this clause is not supplied or NO MAXVALUE is
69 specified, then default values will be used. The defaults are 263-1
70 and -1 for ascending and descending sequences, respectively.
71
72 start
73 The optional clause START WITH start allows the sequence to begin
74 anywhere. The default starting value is minvalue for ascending
75 sequences and maxvalue for descending ones.
76
77 cache
78 The optional clause CACHE cache specifies how many sequence numbers
79 are to be preallocated and stored in memory for faster access. The
80 minimum value is 1 (only one value can be generated at a time,
81 i.e., no cache), and this is also the default.
82
83 CYCLE, NO CYCLE
84 The CYCLE option allows the sequence to wrap around when the
85 maxvalue or minvalue has been reached by an ascending or descending
86 sequence respectively. If the limit is reached, the next number
87 generated will be the minvalue or maxvalue, respectively.
88
89 If NO CYCLE is specified, any calls to nextval after the sequence
90 has reached its maximum value will return an error. If neither
91 CYCLE or NO CYCLE are specified, NO CYCLE is the default.
92
93 OWNED BY table_name.column_name, OWNED BY NONE
94 The OWNED BY option causes the sequence to be associated with a
95 specific table column, such that if that column (or its whole
96 table) is dropped, the sequence will be automatically dropped as
97 well. The specified table must have the same owner and be in the
98 same schema as the sequence. OWNED BY NONE, the default, specifies
99 that there is no such association.
100
102 Use DROP SEQUENCE to remove a sequence.
103
104 Sequences are based on bigint arithmetic, so the range cannot exceed
105 the range of an eight-byte integer (-9223372036854775808 to
106 9223372036854775807).
107
108 Unexpected results might be obtained if a cache setting greater than
109 one is used for a sequence object that will be used concurrently by
110 multiple sessions. Each session will allocate and cache successive
111 sequence values during one access to the sequence object and increase
112 the sequence object's last_value accordingly. Then, the next cache-1
113 uses of nextval within that session simply return the preallocated
114 values without touching the sequence object. So, any numbers allocated
115 but not used within a session will be lost when that session ends,
116 resulting in “holes” in the sequence.
117
118 Furthermore, although multiple sessions are guaranteed to allocate
119 distinct sequence values, the values might be generated out of sequence
120 when all the sessions are considered. For example, with a cache setting
121 of 10, session A might reserve values 1..10 and return nextval=1, then
122 session B might reserve values 11..20 and return nextval=11 before
123 session A has generated nextval=2. Thus, with a cache setting of one it
124 is safe to assume that nextval values are generated sequentially; with
125 a cache setting greater than one you should only assume that the
126 nextval values are all distinct, not that they are generated purely
127 sequentially. Also, last_value will reflect the latest value reserved
128 by any session, whether or not it has yet been returned by nextval.
129
130 Another consideration is that a setval executed on such a sequence will
131 not be noticed by other sessions until they have used up any
132 preallocated values they have cached.
133
135 Create an ascending sequence called serial, starting at 101:
136
137 CREATE SEQUENCE serial START 101;
138
139 Select the next number from this sequence:
140
141 SELECT nextval('serial');
142
143 nextval
144 ---------
145 101
146
147 Select the next number from this sequence:
148
149 SELECT nextval('serial');
150
151 nextval
152 ---------
153 102
154
155 Use this sequence in an INSERT command:
156
157 INSERT INTO distributors VALUES (nextval('serial'), 'nothing');
158
159 Update the sequence value after a COPY FROM:
160
161 BEGIN;
162 COPY distributors FROM 'input_file';
163 SELECT setval('serial', max(id)) FROM distributors;
164 END;
165
167 CREATE SEQUENCE conforms to the SQL standard, with the following
168 exceptions:
169
170 · The standard's AS <data type> expression is not supported.
171
172 · Obtaining the next value is done using the nextval() function
173 instead of the standard's NEXT VALUE FOR expression.
174
175 · The OWNED BY clause is a PostgreSQL extension.
176
178 ALTER SEQUENCE (ALTER_SEQUENCE(7)), DROP SEQUENCE (DROP_SEQUENCE(7))
179
180
181
182PostgreSQL 9.2.24 2017-11-06 CREATE SEQUENCE(7)