File: functions-sequence.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 (711 lines) | stat: -rw-r--r-- 12,919 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
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<HTML
><HEAD
><TITLE
>Sequence Manipulation Functions</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="Functions and Operators"
HREF="functions.html"><LINK
REL="PREVIOUS"
TITLE="XML Functions"
HREF="functions-xml.html"><LINK
REL="NEXT"
TITLE="Conditional Expressions"
HREF="functions-conditional.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="SECT1"
><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="XML Functions"
HREF="functions-xml.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="functions.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 9. Functions and Operators</TD
><TD
WIDTH="20%"
ALIGN="right"
VALIGN="top"
><A
TITLE="Conditional Expressions"
HREF="functions-conditional.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="FUNCTIONS-SEQUENCE"
>9.15. Sequence Manipulation Functions</A
></H1
><P
>   This section describes functions for operating on <I
CLASS="FIRSTTERM"
>sequence
   objects</I
>, also called sequence generators or just sequences.
   Sequence objects are special single-row tables created with <A
HREF="sql-createsequence.html"
>CREATE SEQUENCE</A
>.
   Sequence objects are commonly used to generate unique identifiers
   for rows of a table.  The sequence functions, listed in <A
HREF="functions-sequence.html#FUNCTIONS-SEQUENCE-TABLE"
>Table 9-40</A
>, provide simple, multiuser-safe
   methods for obtaining successive sequence values from sequence
   objects.
  </P
><DIV
CLASS="TABLE"
><A
NAME="FUNCTIONS-SEQUENCE-TABLE"
></A
><P
><B
>Table 9-40. Sequence Functions</B
></P
><TABLE
BORDER="1"
CLASS="CALSTABLE"
><COL><COL><COL><THEAD
><TR
><TH
>Function</TH
><TH
>Return Type</TH
><TH
>Description</TH
></TR
></THEAD
><TBODY
><TR
><TD
><TT
CLASS="LITERAL"
><CODE
CLASS="FUNCTION"
>currval(<TT
CLASS="TYPE"
>regclass</TT
>)</CODE
></TT
></TD
><TD
><TT
CLASS="TYPE"
>bigint</TT
></TD
><TD
>Return value most recently obtained with
        <CODE
CLASS="FUNCTION"
>nextval</CODE
> for specified sequence</TD
></TR
><TR
><TD
><TT
CLASS="LITERAL"
><CODE
CLASS="FUNCTION"
>lastval()</CODE
></TT
></TD
><TD
><TT
CLASS="TYPE"
>bigint</TT
></TD
><TD
>Return value most recently obtained with
        <CODE
CLASS="FUNCTION"
>nextval</CODE
> for any sequence</TD
></TR
><TR
><TD
><TT
CLASS="LITERAL"
><CODE
CLASS="FUNCTION"
>nextval(<TT
CLASS="TYPE"
>regclass</TT
>)</CODE
></TT
></TD
><TD
><TT
CLASS="TYPE"
>bigint</TT
></TD
><TD
>Advance sequence and return new value</TD
></TR
><TR
><TD
><TT
CLASS="LITERAL"
><CODE
CLASS="FUNCTION"
>setval(<TT
CLASS="TYPE"
>regclass</TT
>, <TT
CLASS="TYPE"
>bigint</TT
>)</CODE
></TT
></TD
><TD
><TT
CLASS="TYPE"
>bigint</TT
></TD
><TD
>Set sequence's current value</TD
></TR
><TR
><TD
><TT
CLASS="LITERAL"
><CODE
CLASS="FUNCTION"
>setval(<TT
CLASS="TYPE"
>regclass</TT
>, <TT
CLASS="TYPE"
>bigint</TT
>, <TT
CLASS="TYPE"
>boolean</TT
>)</CODE
></TT
></TD
><TD
><TT
CLASS="TYPE"
>bigint</TT
></TD
><TD
>Set sequence's current value and <TT
CLASS="LITERAL"
>is_called</TT
> flag</TD
></TR
></TBODY
></TABLE
></DIV
><P
>   The sequence to be operated on by a sequence function is specified by
   a <TT
CLASS="TYPE"
>regclass</TT
> argument, which is simply the OID of the sequence in the
   <TT
CLASS="STRUCTNAME"
>pg_class</TT
> system catalog.  You do not have to look up the
   OID by hand, however, since the <TT
CLASS="TYPE"
>regclass</TT
> data type's input
   converter will do the work for you.  Just write the sequence name enclosed
   in single quotes so that it looks like a literal constant.  For
   compatibility with the handling of ordinary
   <ACRONYM
CLASS="ACRONYM"
>SQL</ACRONYM
> names, the string will be converted to lower case
   unless it contains double quotes around the sequence name.  Thus:
</P><PRE
CLASS="PROGRAMLISTING"
>nextval('foo')      <I
CLASS="LINEANNOTATION"
>operates on sequence <TT
CLASS="LITERAL"
>foo</TT
></I
>
nextval('FOO')      <I
CLASS="LINEANNOTATION"
>operates on sequence <TT
CLASS="LITERAL"
>foo</TT
></I
>
nextval('"Foo"')    <I
CLASS="LINEANNOTATION"
>operates on sequence <TT
CLASS="LITERAL"
>Foo</TT
></I
></PRE
><P>
   The sequence name can be schema-qualified if necessary:
</P><PRE
CLASS="PROGRAMLISTING"
>nextval('myschema.foo')     <I
CLASS="LINEANNOTATION"
>operates on <TT
CLASS="LITERAL"
>myschema.foo</TT
></I
>
nextval('"myschema".foo')   <I
CLASS="LINEANNOTATION"
>same as above</I
>
nextval('foo')              <I
CLASS="LINEANNOTATION"
>searches search path for <TT
CLASS="LITERAL"
>foo</TT
></I
></PRE
><P>
   See <A
HREF="datatype-oid.html"
>Section 8.16</A
> for more information about
   <TT
CLASS="TYPE"
>regclass</TT
>.
  </P
><DIV
CLASS="NOTE"
><BLOCKQUOTE
CLASS="NOTE"
><P
><B
>Note: </B
>    Before <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> 8.1, the arguments of the
    sequence functions were of type <TT
CLASS="TYPE"
>text</TT
>, not <TT
CLASS="TYPE"
>regclass</TT
>, and
    the above-described conversion from a text string to an OID value would
    happen at run time during each call.  For backward compatibility, this
    facility still exists, but internally it is now handled as an implicit
    coercion from <TT
CLASS="TYPE"
>text</TT
> to <TT
CLASS="TYPE"
>regclass</TT
> before the function is
    invoked.
   </P
><P
>    When you write the argument of a sequence function as an unadorned
    literal string, it becomes a constant of type <TT
CLASS="TYPE"
>regclass</TT
>.
    Since this is really just an OID, it will track the originally
    identified sequence despite later renaming, schema reassignment,
    etc.  This <SPAN
CLASS="QUOTE"
>"early binding"</SPAN
> behavior is usually desirable for
    sequence references in column defaults and views.  But sometimes you might
    want <SPAN
CLASS="QUOTE"
>"late binding"</SPAN
> where the sequence reference is resolved
    at run time.  To get late-binding behavior, force the constant to be
    stored as a <TT
CLASS="TYPE"
>text</TT
> constant instead of <TT
CLASS="TYPE"
>regclass</TT
>:
</P><PRE
CLASS="PROGRAMLISTING"
>nextval('foo'::text)      <I
CLASS="LINEANNOTATION"
><TT
CLASS="LITERAL"
>foo</TT
> is looked up at runtime</I
></PRE
><P>
    Note that late binding was the only behavior supported in
    <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> releases before 8.1, so you
    might need to do this to preserve the semantics of old applications.
   </P
><P
>    Of course, the argument of a sequence function can be an expression
    as well as a constant.  If it is a text expression then the implicit
    coercion will result in a run-time lookup.
   </P
></BLOCKQUOTE
></DIV
><P
>   The available sequence functions are:

    <P
></P
></P><DIV
CLASS="VARIABLELIST"
><DL
><DT
><CODE
CLASS="FUNCTION"
>nextval</CODE
></DT
><DD
><P
>        Advance the sequence object to its next value and return that
        value.  This is done atomically: even if multiple sessions
        execute <CODE
CLASS="FUNCTION"
>nextval</CODE
> concurrently, each will safely receive
        a distinct sequence value.
       </P
><P
>        If a sequence object has been created with default parameters,
        successive <CODE
CLASS="FUNCTION"
>nextval</CODE
> calls will return successive
        values beginning with 1.  Other behaviors can be obtained by using
        special parameters in the <A
HREF="sql-createsequence.html"
>CREATE SEQUENCE</A
> command;
        see its command reference page for more information.
       </P
><DIV
CLASS="IMPORTANT"
><BLOCKQUOTE
CLASS="IMPORTANT"
><P
><B
>Important: </B
>         To avoid blocking concurrent transactions that obtain numbers from the
         same sequence, a <CODE
CLASS="FUNCTION"
>nextval</CODE
> operation is never
         rolled back; that is, once a value has been fetched it is considered
         used, even if the transaction that did the
         <CODE
CLASS="FUNCTION"
>nextval</CODE
> later aborts.  This means that aborted
         transactions might leave unused <SPAN
CLASS="QUOTE"
>"holes"</SPAN
> in the sequence
         of assigned values.
        </P
></BLOCKQUOTE
></DIV
></DD
><DT
><CODE
CLASS="FUNCTION"
>currval</CODE
></DT
><DD
><P
>        Return the value most recently obtained by <CODE
CLASS="FUNCTION"
>nextval</CODE
>
        for this sequence in the current session.  (An error is
        reported if <CODE
CLASS="FUNCTION"
>nextval</CODE
> has never been called for this
        sequence in this session.)  Because this is returning
        a session-local value, it gives a predictable answer whether or not
        other sessions have executed <CODE
CLASS="FUNCTION"
>nextval</CODE
> since the
        current session did.
       </P
></DD
><DT
><CODE
CLASS="FUNCTION"
>lastval</CODE
></DT
><DD
><P
>        Return the value most recently returned by
        <CODE
CLASS="FUNCTION"
>nextval</CODE
> in the current session. This function is
        identical to <CODE
CLASS="FUNCTION"
>currval</CODE
>, except that instead
        of taking the sequence name as an argument it fetches the
        value of the last sequence used by <CODE
CLASS="FUNCTION"
>nextval</CODE
>
        in the current session. It is an error to call
        <CODE
CLASS="FUNCTION"
>lastval</CODE
> if <CODE
CLASS="FUNCTION"
>nextval</CODE
>
        has not yet been called in the current session.
       </P
></DD
><DT
><CODE
CLASS="FUNCTION"
>setval</CODE
></DT
><DD
><P
>        Reset the sequence object's counter value.  The two-parameter
        form sets the sequence's <TT
CLASS="LITERAL"
>last_value</TT
> field to the
        specified value and sets its <TT
CLASS="LITERAL"
>is_called</TT
> field to
        <TT
CLASS="LITERAL"
>true</TT
>, meaning that the next
        <CODE
CLASS="FUNCTION"
>nextval</CODE
> will advance the sequence before
        returning a value.  The value reported by <CODE
CLASS="FUNCTION"
>currval</CODE
> is
        also set to the specified value.  In the three-parameter form,
        <TT
CLASS="LITERAL"
>is_called</TT
> can be set to either <TT
CLASS="LITERAL"
>true</TT
>
        or <TT
CLASS="LITERAL"
>false</TT
>.  <TT
CLASS="LITERAL"
>true</TT
> has the same effect as
        the two-parameter form. If it is set to <TT
CLASS="LITERAL"
>false</TT
>, the
        next <CODE
CLASS="FUNCTION"
>nextval</CODE
> will return exactly the specified
        value, and sequence advancement commences with the following
        <CODE
CLASS="FUNCTION"
>nextval</CODE
>.  Furthermore, the value reported by
        <CODE
CLASS="FUNCTION"
>currval</CODE
> is not changed in this case (this is a change
        from pre-8.3 behavior).  For example,

</P><PRE
CLASS="SCREEN"
>SELECT setval('foo', 42);           <I
CLASS="LINEANNOTATION"
>Next <CODE
CLASS="FUNCTION"
>nextval</CODE
> will return 43</I
>
SELECT setval('foo', 42, true);     <I
CLASS="LINEANNOTATION"
>Same as above</I
>
SELECT setval('foo', 42, false);    <I
CLASS="LINEANNOTATION"
>Next <CODE
CLASS="FUNCTION"
>nextval</CODE
> will return 42</I
></PRE
><P>

        The result returned by <CODE
CLASS="FUNCTION"
>setval</CODE
> is just the value of its
        second argument.
       </P
><DIV
CLASS="IMPORTANT"
><BLOCKQUOTE
CLASS="IMPORTANT"
><P
><B
>Important: </B
>         Because sequences are non-transactional, changes made by
         <CODE
CLASS="FUNCTION"
>setval</CODE
> are not undone if the transaction rolls
         back.
        </P
></BLOCKQUOTE
></DIV
></DD
></DL
></DIV
><P>
  </P
></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="functions-xml.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="functions-conditional.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>XML Functions</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="functions.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>Conditional Expressions</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>