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
|
<?xml version="1.0" encoding="UTF-8" standalone="no"?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>9.17. Sequence Manipulation Functions</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets V1.79.1" /><link rel="prev" href="functions-json.html" title="9.16. JSON Functions and Operators" /><link rel="next" href="functions-conditional.html" title="9.18. Conditional Expressions" /></head><body id="docContent" class="container-fluid col-10"><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">9.17. Sequence Manipulation Functions</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="functions-json.html" title="9.16. JSON Functions and Operators">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><th width="60%" align="center">Chapter 9. Functions and Operators</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 13.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="functions-conditional.html" title="9.18. Conditional Expressions">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="FUNCTIONS-SEQUENCE"><div class="titlepage"><div><div><h2 class="title" style="clear: both">9.17. Sequence Manipulation Functions</h2></div></div></div><a id="id-1.5.8.23.2" class="indexterm"></a><p>
This section describes functions for operating on <em class="firstterm">sequence
objects</em>, also called sequence generators or just sequences.
Sequence objects are special single-row tables created with <a class="xref" href="sql-createsequence.html" title="CREATE SEQUENCE"><span class="refentrytitle">CREATE SEQUENCE</span></a>.
Sequence objects are commonly used to generate unique identifiers
for rows of a table. The sequence functions, listed in <a class="xref" href="functions-sequence.html#FUNCTIONS-SEQUENCE-TABLE" title="Table 9.50. Sequence Functions">Table 9.50</a>, provide simple, multiuser-safe
methods for obtaining successive sequence values from sequence
objects.
</p><div class="table" id="FUNCTIONS-SEQUENCE-TABLE"><p class="title"><strong>Table 9.50. Sequence Functions</strong></p><div class="table-contents"><table class="table" summary="Sequence Functions" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
Function
</p>
<p>
Description
</p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.23.4.2.2.1.1.1.1" class="indexterm"></a>
<code class="function">nextval</code> ( <code class="type">regclass</code> )
→ <code class="returnvalue">bigint</code>
</p>
<p>
Advances the sequence object to its next value and returns 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.
If the 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
appropriate parameters in the <a class="xref" href="sql-createsequence.html" title="CREATE SEQUENCE"><span class="refentrytitle">CREATE SEQUENCE</span></a>
command.
</p>
<p>
This function requires <code class="literal">USAGE</code>
or <code class="literal">UPDATE</code> privilege on the sequence.
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.23.4.2.2.2.1.1.1" class="indexterm"></a>
<code class="function">setval</code> ( <code class="type">regclass</code>, <code class="type">bigint</code> [<span class="optional">, <code class="type">boolean</code> </span>] )
→ <code class="returnvalue">bigint</code>
</p>
<p>
Sets the sequence object's current value, and optionally
its <code class="literal">is_called</code> flag. The two-parameter
form sets the sequence's <code class="literal">last_value</code> field to the
specified value and sets its <code class="literal">is_called</code> field to
<code class="literal">true</code>, meaning that the next
<code class="function">nextval</code> will advance the sequence before
returning a value. The value that will be reported
by <code class="function">currval</code> is also set to the specified value.
In the three-parameter form, <code class="literal">is_called</code> can be set
to either <code class="literal">true</code>
or <code class="literal">false</code>. <code class="literal">true</code> has the same
effect as the two-parameter form. If it is set
to <code class="literal">false</code>, 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. For example,
</p><pre class="programlisting">
SELECT setval('myseq', 42); <em class="lineannotation"><span class="lineannotation">Next <code class="function">nextval</code> will return 43</span></em>
SELECT setval('myseq', 42, true); <em class="lineannotation"><span class="lineannotation">Same as above</span></em>
SELECT setval('myseq', 42, false); <em class="lineannotation"><span class="lineannotation">Next <code class="function">nextval</code> will return 42</span></em>
</pre><p>
The result returned by <code class="function">setval</code> is just the value of its
second argument.
</p>
<p>
This function requires <code class="literal">UPDATE</code> privilege on the
sequence.
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.23.4.2.2.3.1.1.1" class="indexterm"></a>
<code class="function">currval</code> ( <code class="type">regclass</code> )
→ <code class="returnvalue">bigint</code>
</p>
<p>
Returns 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>
<p>
This function requires <code class="literal">USAGE</code>
or <code class="literal">SELECT</code> privilege on the sequence.
</p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
<a id="id-1.5.8.23.4.2.2.4.1.1.1" class="indexterm"></a>
<code class="function">lastval</code> ()
→ <code class="returnvalue">bigint</code>
</p>
<p>
Returns 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 refers to whichever
sequence <code class="function">nextval</code> was most recently applied to
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>
<p>
This function requires <code class="literal">USAGE</code>
or <code class="literal">SELECT</code> privilege on the last used sequence.
</p></td></tr></tbody></table></div></div><br class="table-break" /><div class="caution"><h3 class="title">Caution</h3><p>
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 and will not be returned again. This is true even if the
surrounding transaction later aborts, or if the calling query ends
up not using the value. For example an <code class="command">INSERT</code> with
an <code class="literal">ON CONFLICT</code> clause will compute the to-be-inserted
tuple, including doing any required <code class="function">nextval</code>
calls, before detecting any conflict that would cause it to follow
the <code class="literal">ON CONFLICT</code> rule instead. Such cases will leave
unused <span class="quote">“<span class="quote">holes</span>”</span> in the sequence of assigned values.
Thus, <span class="productname">PostgreSQL</span> sequence
objects <span class="emphasis"><em>cannot be used to obtain <span class="quote">“<span class="quote">gapless</span>”</span>
sequences</em></span>.
</p><p>
Likewise, any sequence state changes made by <code class="function">setval</code>
are not undone if the transaction rolls back.
</p></div><p>
The sequence to be operated on by a sequence function is specified by
a <code class="type">regclass</code> argument, which is simply the OID of the sequence in the
<code class="structname">pg_class</code> system catalog. You do not have to look up the
OID by hand, however, since the <code class="type">regclass</code> 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') <em class="lineannotation"><span class="lineannotation">operates on sequence <code class="literal">foo</code></span></em>
nextval('FOO') <em class="lineannotation"><span class="lineannotation">operates on sequence <code class="literal">foo</code></span></em>
nextval('"Foo"') <em class="lineannotation"><span class="lineannotation">operates on sequence <code class="literal">Foo</code></span></em>
</pre><p>
The sequence name can be schema-qualified if necessary:
</p><pre class="programlisting">
nextval('myschema.foo') <em class="lineannotation"><span class="lineannotation">operates on <code class="literal">myschema.foo</code></span></em>
nextval('"myschema".foo') <em class="lineannotation"><span class="lineannotation">same as above</span></em>
nextval('foo') <em class="lineannotation"><span class="lineannotation">searches search path for <code class="literal">foo</code></span></em>
</pre><p>
See <a class="xref" href="datatype-oid.html" title="8.19. Object Identifier Types">Section 8.19</a> for more information about
<code class="type">regclass</code>.
</p><div class="note"><h3 class="title">Note</h3><p>
Before <span class="productname">PostgreSQL</span> 8.1, the arguments of the
sequence functions were of type <code class="type">text</code>, not <code class="type">regclass</code>, 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 <code class="type">text</code> to <code class="type">regclass</code> 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 <code class="type">regclass</code>.
Since this is really just an OID, it will track the originally
identified sequence despite later renaming, schema reassignment,
etc. This <span class="quote">“<span class="quote">early binding</span>”</span> behavior is usually desirable for
sequence references in column defaults and views. But sometimes you might
want <span class="quote">“<span class="quote">late binding</span>”</span> where the sequence reference is resolved
at run time. To get late-binding behavior, force the constant to be
stored as a <code class="type">text</code> constant instead of <code class="type">regclass</code>:
</p><pre class="programlisting">
nextval('foo'::text) <em class="lineannotation"><span class="lineannotation"><code class="literal">foo</code> is looked up at runtime</span></em>
</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></div></div><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navfooter"><hr></hr><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="functions-json.html" title="9.16. JSON Functions and Operators">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="functions-conditional.html" title="9.18. Conditional Expressions">Next</a></td></tr><tr><td width="40%" align="left" valign="top">9.16. JSON Functions and Operators </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 13.4 Documentation">Home</a></td><td width="40%" align="right" valign="top"> 9.18. Conditional Expressions</td></tr></table></div></body></html>
|