File: sql-createsequence.html

package info (click to toggle)
postgresql-9.1 9.1.15-0%2Bdeb8u1
  • links: PTS, VCS
  • area: main
  • in suites: jessie-kfreebsd
  • size: 109,092 kB
  • sloc: ansic: 575,877; sql: 43,887; yacc: 26,399; perl: 6,352; lex: 6,171; sh: 5,282; makefile: 3,772; asm: 65; sed: 15; python: 12
file content (830 lines) | stat: -rw-r--r-- 13,842 bytes parent folder | download
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
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<HTML
><HEAD
><TITLE
>CREATE SEQUENCE</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.79"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 9.1.15 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="SQL Commands"
HREF="sql-commands.html"><LINK
REL="PREVIOUS"
TITLE="CREATE SCHEMA"
HREF="sql-createschema.html"><LINK
REL="NEXT"
TITLE="CREATE SERVER"
HREF="sql-createserver.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
HTTP-EQUIV="Content-Type"
CONTENT="text/html; charset=ISO-8859-1"><META
NAME="creation"
CONTENT="2015-02-02T21:03:01"></HEAD
><BODY
CLASS="REFENTRY"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="5"
ALIGN="center"
VALIGN="bottom"
><A
HREF="index.html"
>PostgreSQL 9.1.15 Documentation</A
></TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
TITLE="CREATE SCHEMA"
HREF="sql-createschema.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="sql-commands.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
></TD
><TD
WIDTH="20%"
ALIGN="right"
VALIGN="top"
><A
TITLE="CREATE SERVER"
HREF="sql-createserver.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><H1
><A
NAME="SQL-CREATESEQUENCE"
></A
>CREATE SEQUENCE</H1
><DIV
CLASS="REFNAMEDIV"
><A
NAME="AEN67316"
></A
><H2
>Name</H2
>CREATE SEQUENCE&nbsp;--&nbsp;define a new sequence generator</DIV
><DIV
CLASS="REFSYNOPSISDIV"
><A
NAME="AEN67321"
></A
><H2
>Synopsis</H2
><PRE
CLASS="SYNOPSIS"
>CREATE [ TEMPORARY | TEMP ] SEQUENCE <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
> [ INCREMENT [ BY ] <TT
CLASS="REPLACEABLE"
><I
>increment</I
></TT
> ]
    [ MINVALUE <TT
CLASS="REPLACEABLE"
><I
>minvalue</I
></TT
> | NO MINVALUE ] [ MAXVALUE <TT
CLASS="REPLACEABLE"
><I
>maxvalue</I
></TT
> | NO MAXVALUE ]
    [ START [ WITH ] <TT
CLASS="REPLACEABLE"
><I
>start</I
></TT
> ] [ CACHE <TT
CLASS="REPLACEABLE"
><I
>cache</I
></TT
> ] [ [ NO ] CYCLE ]
    [ OWNED BY { <TT
CLASS="REPLACEABLE"
><I
>table</I
></TT
>.<TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
> | NONE } ]</PRE
></DIV
><DIV
CLASS="REFSECT1"
><A
NAME="AEN67331"
></A
><H2
>Description</H2
><P
>   <TT
CLASS="COMMAND"
>CREATE SEQUENCE</TT
> creates a new sequence number
   generator.  This involves creating and initializing a new special
   single-row table with the name <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
>.  The generator will be
   owned by the user issuing the command.
  </P
><P
>   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 sequence,
   table, index, view, or foreign table in the same schema.
  </P
><P
>   After a sequence is created, you use the functions
   <CODE
CLASS="FUNCTION"
>nextval</CODE
>,
   <CODE
CLASS="FUNCTION"
>currval</CODE
>, and
   <CODE
CLASS="FUNCTION"
>setval</CODE
>
   to operate on the sequence.  These functions are documented in
   <A
HREF="functions-sequence.html"
>Section 9.15</A
>.
  </P
><P
>   Although you cannot update a sequence directly, you can use a query like:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT * FROM <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
>;</PRE
><P>

   to examine the parameters and current state of a sequence.  In particular,
   the <TT
CLASS="LITERAL"
>last_value</TT
> 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
   <CODE
CLASS="FUNCTION"
>nextval</CODE
> calls.)
  </P
></DIV
><DIV
CLASS="REFSECT1"
><A
NAME="AEN67347"
></A
><H2
>Parameters</H2
><P
></P
><DIV
CLASS="VARIABLELIST"
><DL
><DT
><TT
CLASS="LITERAL"
>TEMPORARY</TT
> or <TT
CLASS="LITERAL"
>TEMP</TT
></DT
><DD
><P
>      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.
     </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
></DT
><DD
><P
>      The name (optionally schema-qualified) of the sequence to be created.
     </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>increment</I
></TT
></DT
><DD
><P
>      The optional clause <TT
CLASS="LITERAL"
>INCREMENT BY <TT
CLASS="REPLACEABLE"
><I
>increment</I
></TT
></TT
> 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.
     </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>minvalue</I
></TT
><BR><TT
CLASS="LITERAL"
>NO MINVALUE</TT
></DT
><DD
><P
>      The optional clause <TT
CLASS="LITERAL"
>MINVALUE <TT
CLASS="REPLACEABLE"
><I
>minvalue</I
></TT
></TT
> determines
      the minimum value a sequence can generate. If this clause is not
      supplied or <TT
CLASS="OPTION"
>NO MINVALUE</TT
> is specified, then
      defaults will be used.  The defaults are 1 and
      -2<SUP
>63</SUP
>-1 for ascending and descending sequences,
      respectively.
     </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>maxvalue</I
></TT
><BR><TT
CLASS="LITERAL"
>NO MAXVALUE</TT
></DT
><DD
><P
>      The optional clause <TT
CLASS="LITERAL"
>MAXVALUE <TT
CLASS="REPLACEABLE"
><I
>maxvalue</I
></TT
></TT
> determines
      the maximum value for the sequence. If this clause is not
      supplied or <TT
CLASS="OPTION"
>NO MAXVALUE</TT
> is specified, then
      default values will be used.  The defaults are
      2<SUP
>63</SUP
>-1 and -1 for ascending and descending
      sequences, respectively.
     </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>start</I
></TT
></DT
><DD
><P
>      The optional clause <TT
CLASS="LITERAL"
>START WITH <TT
CLASS="REPLACEABLE"
><I
>start</I
></TT
> </TT
> allows the
      sequence to begin anywhere.  The default starting value is
      <TT
CLASS="REPLACEABLE"
><I
>minvalue</I
></TT
> for
      ascending sequences and <TT
CLASS="REPLACEABLE"
><I
>maxvalue</I
></TT
> for descending ones.
     </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>cache</I
></TT
></DT
><DD
><P
>      The optional clause <TT
CLASS="LITERAL"
>CACHE <TT
CLASS="REPLACEABLE"
><I
>cache</I
></TT
></TT
> 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.
     </P
></DD
><DT
><TT
CLASS="LITERAL"
>CYCLE</TT
><BR><TT
CLASS="LITERAL"
>NO CYCLE</TT
></DT
><DD
><P
>      The <TT
CLASS="LITERAL"
>CYCLE</TT
> option allows the sequence to wrap
      around when the <TT
CLASS="REPLACEABLE"
><I
>maxvalue</I
></TT
> or <TT
CLASS="REPLACEABLE"
><I
>minvalue</I
></TT
> has been reached by an
      ascending or descending sequence respectively. If the limit is
      reached, the next number generated will be the <TT
CLASS="REPLACEABLE"
><I
>minvalue</I
></TT
> or <TT
CLASS="REPLACEABLE"
><I
>maxvalue</I
></TT
>, respectively.
     </P
><P
>      If <TT
CLASS="LITERAL"
>NO CYCLE</TT
> is specified, any calls to
      <CODE
CLASS="FUNCTION"
>nextval</CODE
> after the sequence has reached its
      maximum value will return an error.  If neither
      <TT
CLASS="LITERAL"
>CYCLE</TT
> or <TT
CLASS="LITERAL"
>NO CYCLE</TT
> are
      specified, <TT
CLASS="LITERAL"
>NO CYCLE</TT
> is the default.
     </P
></DD
><DT
><TT
CLASS="LITERAL"
>OWNED BY</TT
> <TT
CLASS="REPLACEABLE"
><I
>table</I
></TT
>.<TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
><BR><TT
CLASS="LITERAL"
>OWNED BY NONE</TT
></DT
><DD
><P
>      The <TT
CLASS="LITERAL"
>OWNED BY</TT
> 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.
      <TT
CLASS="LITERAL"
>OWNED BY NONE</TT
>, the default, specifies that there
      is no such association.
     </P
></DD
></DL
></DIV
></DIV
><DIV
CLASS="REFSECT1"
><A
NAME="AEN67435"
></A
><H2
>Notes</H2
><P
>   Use <TT
CLASS="COMMAND"
>DROP SEQUENCE</TT
> to remove a sequence.
  </P
><P
>   Sequences are based on <TT
CLASS="TYPE"
>bigint</TT
> arithmetic, so the range
   cannot exceed the range of an eight-byte integer
   (-9223372036854775808 to 9223372036854775807).
  </P
><P
>   Unexpected results might be obtained if a <TT
CLASS="REPLACEABLE"
><I
>cache</I
></TT
> 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 <TT
CLASS="LITERAL"
>last_value</TT
> accordingly.
   Then, the next <TT
CLASS="REPLACEABLE"
><I
>cache</I
></TT
>-1
   uses of <CODE
CLASS="FUNCTION"
>nextval</CODE
> 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 <SPAN
CLASS="QUOTE"
>"holes"</SPAN
> in the
   sequence.
  </P
><P
>   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 <TT
CLASS="REPLACEABLE"
><I
>cache</I
></TT
> setting of 10,
   session A might reserve values 1..10 and return
   <CODE
CLASS="FUNCTION"
>nextval</CODE
>=1, then session B might reserve values
   11..20 and return <CODE
CLASS="FUNCTION"
>nextval</CODE
>=11 before session A
   has generated <TT
CLASS="LITERAL"
>nextval</TT
>=2.  Thus, with a
   <TT
CLASS="REPLACEABLE"
><I
>cache</I
></TT
> setting of one
   it is safe to assume that <CODE
CLASS="FUNCTION"
>nextval</CODE
> values are generated
   sequentially; with a <TT
CLASS="REPLACEABLE"
><I
>cache</I
></TT
> setting greater than one you
   should only assume that the <CODE
CLASS="FUNCTION"
>nextval</CODE
> values are all
   distinct, not that they are generated purely sequentially.  Also,
   <TT
CLASS="LITERAL"
>last_value</TT
> will reflect the latest value reserved by
   any session, whether or not it has yet been returned by
   <CODE
CLASS="FUNCTION"
>nextval</CODE
>.
  </P
><P
>   Another consideration is that a <CODE
CLASS="FUNCTION"
>setval</CODE
> executed on
   such a sequence will not be noticed by other sessions until they
   have used up any preallocated values they have cached.
  </P
></DIV
><DIV
CLASS="REFSECT1"
><A
NAME="AEN67460"
></A
><H2
>Examples</H2
><P
>   Create an ascending sequence called <TT
CLASS="LITERAL"
>serial</TT
>, starting at 101:
</P><PRE
CLASS="PROGRAMLISTING"
>CREATE SEQUENCE serial START 101;</PRE
><P>
  </P
><P
>   Select the next number from this sequence:
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT nextval('serial');

 nextval
---------
     101</PRE
><P>
  </P
><P
>   Select the next number from this sequence:
</P><PRE
CLASS="PROGRAMLISTING"
>SELECT nextval('serial');

 nextval
---------
     102</PRE
><P>
  </P
><P
>   Use this sequence in an <TT
CLASS="COMMAND"
>INSERT</TT
> command:
</P><PRE
CLASS="PROGRAMLISTING"
>INSERT INTO distributors VALUES (nextval('serial'), 'nothing');</PRE
><P>
  </P
><P
>   Update the sequence value after a <TT
CLASS="COMMAND"
>COPY FROM</TT
>:
</P><PRE
CLASS="PROGRAMLISTING"
>BEGIN;
COPY distributors FROM 'input_file';
SELECT setval('serial', max(id)) FROM distributors;
END;</PRE
><P></P
></DIV
><DIV
CLASS="REFSECT1"
><A
NAME="AEN67475"
></A
><H2
>Compatibility</H2
><P
>   <TT
CLASS="COMMAND"
>CREATE SEQUENCE</TT
> conforms to the <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
>
   standard, with the following exceptions:
   <P
></P
></P><UL
><LI
><P
>      The standard's <TT
CLASS="LITERAL"
>AS &lt;data type&gt;</TT
> expression is not
      supported.
     </P
></LI
><LI
><P
>      Obtaining the next value is done using the <CODE
CLASS="FUNCTION"
>nextval()</CODE
>
      function instead of the standard's <TT
CLASS="COMMAND"
>NEXT VALUE FOR</TT
>
      expression.
     </P
></LI
><LI
><P
>      The <TT
CLASS="LITERAL"
>OWNED BY</TT
> clause is a <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
>
      extension.
     </P
></LI
></UL
><P></P
></DIV
><DIV
CLASS="REFSECT1"
><A
NAME="AEN67492"
></A
><H2
>See Also</H2
><A
HREF="sql-altersequence.html"
>ALTER SEQUENCE</A
>, <A
HREF="sql-dropsequence.html"
>DROP SEQUENCE</A
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="sql-createschema.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="sql-createserver.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>CREATE SCHEMA</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="sql-commands.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>CREATE SERVER</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>