mirror of
https://github.com/postgres/postgres.git
synced 2025-12-19 17:02:53 +03:00
locate the target row, if the cursor was declared with FOR UPDATE or FOR SHARE. This approach is more flexible and reliable than digging through the plan tree; for instance it can cope with join cursors. But we still provide the old code for use with non-FOR-UPDATE cursors. Per gripe from Robert Haas.
329 lines
12 KiB
Plaintext
329 lines
12 KiB
Plaintext
<!--
|
|
$PostgreSQL: pgsql/doc/src/sgml/ref/declare.sgml,v 1.45 2008/11/16 17:34:28 tgl Exp $
|
|
PostgreSQL documentation
|
|
-->
|
|
|
|
<refentry id="SQL-DECLARE">
|
|
<refmeta>
|
|
<refentrytitle id="SQL-DECLARE-TITLE">DECLARE</refentrytitle>
|
|
<manvolnum>7</manvolnum>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>DECLARE</refname>
|
|
<refpurpose>define a cursor</refpurpose>
|
|
</refnamediv>
|
|
|
|
<indexterm zone="sql-declare">
|
|
<primary>DECLARE</primary>
|
|
</indexterm>
|
|
|
|
<indexterm zone="sql-declare">
|
|
<primary>cursor</primary>
|
|
<secondary>DECLARE</secondary>
|
|
</indexterm>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ]
|
|
CURSOR [ { WITH | WITHOUT } HOLD ] FOR <replaceable class="parameter">query</replaceable>
|
|
</synopsis>
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1>
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
<command>DECLARE</command> allows a user to create cursors, which
|
|
can be used to retrieve
|
|
a small number of rows at a time out of a larger query.
|
|
After the cursor is created, rows are fetched from it using
|
|
<xref linkend="sql-fetch" endterm="sql-fetch-title">.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Parameters</title>
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name of the cursor to be created.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>BINARY</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Causes the cursor to return data in binary rather than in text format.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>INSENSITIVE</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Indicates that data retrieved from the cursor should be
|
|
unaffected by updates to the table(s) underlying the cursor that occur
|
|
after the cursor is created. In <productname>PostgreSQL</productname>,
|
|
this is the default behavior; so this key word has no
|
|
effect and is only accepted for compatibility with the SQL standard.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>SCROLL</literal></term>
|
|
<term><literal>NO SCROLL</literal></term>
|
|
<listitem>
|
|
<para>
|
|
<literal>SCROLL</literal> specifies that the cursor can be used
|
|
to retrieve rows in a nonsequential fashion (e.g.,
|
|
backward). Depending upon the complexity of the query's
|
|
execution plan, specifying <literal>SCROLL</literal> might impose
|
|
a performance penalty on the query's execution time.
|
|
<literal>NO SCROLL</literal> specifies that the cursor cannot be
|
|
used to retrieve rows in a nonsequential fashion. The default is to
|
|
allow scrolling in some cases; this is not the same as specifying
|
|
<literal>SCROLL</literal>. See <xref linkend="sql-declare-notes"
|
|
endterm="sql-declare-notes-title"> for details.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>WITH HOLD</literal></term>
|
|
<term><literal>WITHOUT HOLD</literal></term>
|
|
<listitem>
|
|
<para>
|
|
<literal>WITH HOLD</literal> specifies that the cursor can
|
|
continue to be used after the transaction that created it
|
|
successfully commits. <literal>WITHOUT HOLD</literal> specifies
|
|
that the cursor cannot be used outside of the transaction that
|
|
created it. If neither <literal>WITHOUT HOLD</literal> nor
|
|
<literal>WITH HOLD</literal> is specified, <literal>WITHOUT
|
|
HOLD</literal> is the default.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">query</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
A <xref linkend="sql-select" endterm="sql-select-title"> or
|
|
<xref linkend="sql-values" endterm="sql-values-title"> command
|
|
which will provide the rows to be returned by the cursor.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
|
|
<para>
|
|
The key words <literal>BINARY</literal>,
|
|
<literal>INSENSITIVE</literal>, and <literal>SCROLL</literal> can
|
|
appear in any order.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1 id="sql-declare-notes">
|
|
<title id="sql-declare-notes-title">Notes</title>
|
|
|
|
<para>
|
|
Normal cursors return data in text format, the same as a
|
|
<command>SELECT</> would produce. The <literal>BINARY</> option
|
|
specifies that the cursor should return data in binary format.
|
|
This reduces conversion effort for both the server and client,
|
|
at the cost of more programmer effort to deal with platform-dependent
|
|
binary data formats.
|
|
As an example, if a query returns a value of one from an integer column,
|
|
you would get a string of <literal>1</> with a default cursor,
|
|
whereas with a binary cursor you would get
|
|
a 4-byte field containing the internal representation of the value
|
|
(in big-endian byte order).
|
|
</para>
|
|
|
|
<para>
|
|
Binary cursors should be used carefully. Many applications,
|
|
including <application>psql</application>, are not prepared to
|
|
handle binary cursors and expect data to come back in the text
|
|
format.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
When the client application uses the <quote>extended query</> protocol
|
|
to issue a <command>FETCH</> command, the Bind protocol message
|
|
specifies whether data is to be retrieved in text or binary format.
|
|
This choice overrides the way that the cursor is defined. The concept
|
|
of a binary cursor as such is thus obsolete when using extended query
|
|
protocol — any cursor can be treated as either text or binary.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
Unless <literal>WITH HOLD</literal> is specified, the cursor
|
|
created by this command can only be used within the current
|
|
transaction. Thus, <command>DECLARE</> without <literal>WITH
|
|
HOLD</literal> is useless outside a transaction block: the cursor would
|
|
survive only to the completion of the statement. Therefore
|
|
<productname>PostgreSQL</productname> reports an error if such a
|
|
command is used outside a transaction block.
|
|
Use
|
|
<xref linkend="sql-begin" endterm="sql-begin-title"> and
|
|
<xref linkend="sql-commit" endterm="sql-commit-title">
|
|
(or <xref linkend="sql-rollback" endterm="sql-rollback-title">)
|
|
to define a transaction block.
|
|
</para>
|
|
|
|
<para>
|
|
If <literal>WITH HOLD</literal> is specified and the transaction
|
|
that created the cursor successfully commits, the cursor can
|
|
continue to be accessed by subsequent transactions in the same
|
|
session. (But if the creating transaction is aborted, the cursor
|
|
is removed.) A cursor created with <literal>WITH HOLD</literal>
|
|
is closed when an explicit <command>CLOSE</command> command is
|
|
issued on it, or the session ends. In the current implementation,
|
|
the rows represented by a held cursor are copied into a temporary
|
|
file or memory area so that they remain available for subsequent
|
|
transactions.
|
|
</para>
|
|
|
|
<para>
|
|
<literal>WITH HOLD</literal> may not be specified when the query
|
|
includes <literal>FOR UPDATE</> or <literal>FOR SHARE</>.
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>SCROLL</> option should be specified when defining a
|
|
cursor that will be used to fetch backwards. This is required by
|
|
the SQL standard. However, for compatibility with earlier
|
|
versions, <productname>PostgreSQL</productname> will allow
|
|
backward fetches without <literal>SCROLL</>, if the cursor's query
|
|
plan is simple enough that no extra overhead is needed to support
|
|
it. However, application developers are advised not to rely on
|
|
using backward fetches from a cursor that has not been created
|
|
with <literal>SCROLL</literal>. If <literal>NO SCROLL</> is
|
|
specified, then backward fetches are disallowed in any case.
|
|
</para>
|
|
|
|
<para>
|
|
Backward fetches are also disallowed when the query
|
|
includes <literal>FOR UPDATE</> or <literal>FOR SHARE</>; therefore
|
|
<literal>SCROLL</literal> may not be specified in this case.
|
|
</para>
|
|
|
|
<para>
|
|
If the cursor's query includes <literal>FOR UPDATE</> or <literal>FOR
|
|
SHARE</>, then returned rows are locked at the time they are first
|
|
fetched, in the same way as for a regular
|
|
<xref linkend="sql-select" endterm="sql-select-title"> command with
|
|
these options.
|
|
In addition, the returned rows will be the most up-to-date versions;
|
|
therefore these options provide the equivalent of what the SQL standard
|
|
calls a <quote>sensitive cursor</>. (Specifying <literal>INSENSITIVE</>
|
|
together with <literal>FOR UPDATE</> or <literal>FOR SHARE</> is an error.)
|
|
</para>
|
|
|
|
<caution>
|
|
<para>
|
|
It is generally recommended to use <literal>FOR UPDATE</> if the cursor
|
|
is intended to be used with <command>UPDATE ... WHERE CURRENT OF</> or
|
|
<command>DELETE ... WHERE CURRENT OF</>. Using <literal>FOR UPDATE</>
|
|
prevents other sessions from changing the rows between the time they are
|
|
fetched and the time they are updated. Without <literal>FOR UPDATE</>,
|
|
a subsequent <literal>WHERE CURRENT OF</> command will have no effect if
|
|
the row was changed since the cursor was created.
|
|
</para>
|
|
|
|
<para>
|
|
Another reason to use <literal>FOR UPDATE</> is that without it, a
|
|
subsequent <literal>WHERE CURRENT OF</> might fail if the cursor query
|
|
does not meet the SQL standard's rules for being <quote>simply
|
|
updatable</> (in particular, the cursor must reference just one table
|
|
and not use grouping or <literal>ORDER BY</>). Cursors
|
|
that are not simply updatable might work, or might not, depending on plan
|
|
choice details; so in the worst case, an application might work in testing
|
|
and then fail in production.
|
|
</para>
|
|
|
|
<para>
|
|
The main reason not to use <literal>FOR UPDATE</> with <literal>WHERE
|
|
CURRENT OF</> is if you need the cursor to be scrollable, or to be
|
|
insensitive to the subsequent updates (that is, continue to show the old
|
|
data). If this is a requirement, pay close heed to the caveats shown
|
|
above.
|
|
</para>
|
|
</caution>
|
|
|
|
<para>
|
|
The SQL standard only makes provisions for cursors in embedded
|
|
<acronym>SQL</acronym>. The <productname>PostgreSQL</productname>
|
|
server does not implement an <command>OPEN</command> statement for
|
|
cursors; a cursor is considered to be open when it is declared.
|
|
However, <application>ECPG</application>, the embedded SQL
|
|
preprocessor for <productname>PostgreSQL</productname>, supports
|
|
the standard SQL cursor conventions, including those involving
|
|
<command>DECLARE</command> and <command>OPEN</command> statements.
|
|
</para>
|
|
|
|
<para>
|
|
You can see all available cursors by querying the <link
|
|
linkend="view-pg-cursors"><structname>pg_cursors</structname></link>
|
|
system view.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Examples</title>
|
|
|
|
<para>
|
|
To declare a cursor:
|
|
<programlisting>
|
|
DECLARE liahona CURSOR FOR SELECT * FROM films;
|
|
</programlisting>
|
|
See <xref linkend="sql-fetch" endterm="sql-fetch-title"> for more
|
|
examples of cursor usage.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
The SQL standard says that it is implementation-dependent whether cursors
|
|
are sensitive to concurrent updates of the underlying data by default. In
|
|
<productname>PostgreSQL</productname>, cursors are insensitive by default,
|
|
and can be made sensitive by specifying <literal>FOR UPDATE</>. Other
|
|
products may work differently.
|
|
</para>
|
|
|
|
<para>
|
|
The SQL standard allows cursors only in embedded
|
|
<acronym>SQL</acronym> and in modules. <productname>PostgreSQL</>
|
|
permits cursors to be used interactively.
|
|
</para>
|
|
|
|
<para>
|
|
Binary cursors are a <productname>PostgreSQL</productname>
|
|
extension.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>See Also</title>
|
|
|
|
<simplelist type="inline">
|
|
<member><xref linkend="sql-close" endterm="sql-close-title"></member>
|
|
<member><xref linkend="sql-fetch" endterm="sql-fetch-title"></member>
|
|
<member><xref linkend="sql-move" endterm="sql-move-title"></member>
|
|
</simplelist>
|
|
</refsect1>
|
|
</refentry>
|