1CREATE SEQUENCE()                SQL Commands                CREATE SEQUENCE()
2
3
4

NAME

6       CREATE SEQUENCE - define a new sequence generator
7
8

SYNOPSIS

10       CREATE [ TEMPORARY | TEMP ] SEQUENCE name [ INCREMENT [ BY ] increment ]
11           [ MINVALUE minvalue | NO MINVALUE ] [ MAXVALUE maxvalue | NO MAXVALUE ]
12           [ START [ WITH ] start ] [ CACHE cache ] [ [ NO ] CYCLE ]
13           [ OWNED BY { table.column | NONE } ]
14
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 may not be given
24       when creating a temporary sequence.  The sequence name must be distinct
25       from  the name of any other sequence, table, index, or view in the same
26       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 in the documentation.
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 particu‐
38       lar, the last_value field of the sequence shows the  last  value  allo‐
39       cated  by  any  session.  (Of course, this value may be obsolete by the
40       time it's printed, if other sessions are actively doing nextval calls.)
41

PARAMETERS

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

NOTES

111       Use DROP SEQUENCE to remove a sequence.
112
113       Sequences  are  based  on bigint arithmetic, so the range cannot exceed
114       the  range  of   an   eight-byte   integer   (-9223372036854775808   to
115       9223372036854775807). On some older platforms, there may be no compiler
116       support for eight-byte integers, in which case  sequences  use  regular
117       integer arithmetic (range -2147483648 to +2147483647).
118
119       Unexpected  results may be obtained if a cache setting greater than one
120       is used for a sequence object that will be used concurrently by  multi‐
121       ple  sessions. Each session will allocate and cache successive sequence
122       values during one access  to  the  sequence  object  and  increase  the
123       sequence  object's last_value accordingly.  Then, the next cache-1 uses
124       of nextval within that session simply return  the  preallocated  values
125       without touching the sequence object. So, any numbers allocated but not
126       used within a session will be lost when that session ends, resulting in
127       ``holes'' in the sequence.
128
129       Furthermore, although multiple sessions are guaranteed to allocate dis‐
130       tinct sequence values, the values may be generated out of sequence when
131       all  the  sessions are considered. For example, with a cache setting of
132       10, session A might reserve values 1..10  and  return  nextval=1,  then
133       session B might reserve values 11..20 and return nextval=11 before ses‐
134       sion A has generated nextval=2. Thus, with a cache setting of one it is
135       safe  to  assume that nextval values are generated sequentially; with a
136       cache setting greater than one you should only assume that the  nextval
137       values  are  all  distinct,  not that they are generated purely sequen‐
138       tially. Also, last_value will reflect the latest value reserved by  any
139       session, whether or not it has yet been returned by nextval.
140
141       Another consideration is that a setval executed on such a sequence will
142       not be noticed by other sessions until they have used up  any  preallo‐
143       cated values they have cached.
144

EXAMPLES

146       Create an ascending sequence called serial, starting at 101:
147
148       CREATE SEQUENCE serial START 101;
149
150
151       Select the next number from this sequence:
152
153       SELECT nextval('serial');
154
155        nextval
156       ---------
157            114
158
159
160       Use this sequence in an INSERT command:
161
162       INSERT INTO distributors VALUES (nextval('serial'), 'nothing');
163
164
165       Update the sequence value after a COPY FROM:
166
167       BEGIN;
168       COPY distributors FROM 'input_file';
169       SELECT setval('serial', max(id)) FROM distributors;
170       END;
171
172

COMPATIBILITY

174       CREATE SEQUENCE conforms to the SQL standard, with the following excep‐
175       tions:
176
177       · The standard's AS <data type> expression is not supported.
178
179       · Obtaining the next value is done using the nextval() function instead
180         of the standard's NEXT VALUE FOR expression.
181
182       · The OWNED BY clause is a PostgreSQL extension.
183

SEE ALSO

185       ALTER SEQUENCE [alter_sequence(7)], DROP SEQUENCE [drop_sequence(l)]
186
187
188
189SQL - Language Statements         2008-06-08                 CREATE SEQUENCE()
Impressum