1DECLARE() SQL Commands DECLARE()
2
3
4
6 DECLARE - define a cursor
7
8
10 DECLARE name [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ]
11 CURSOR [ { WITH | WITHOUT } HOLD ] FOR query
12 [ FOR { READ ONLY | UPDATE [ OF column [, ...] ] } ]
13
14
16 DECLARE allows a user to create cursors, which can be used to retrieve
17 a small number of rows at a time out of a larger query. Cursors can
18 return data either in text or in binary format using FETCH [fetch(7)].
19
20 Normal cursors return data in text format, the same as a SELECT would
21 produce. Since data is stored natively in binary format, the system
22 must do a conversion to produce the text format. Once the information
23 comes back in text form, the client application may need to convert it
24 to a binary format to manipulate it. In addition, data in the text for‐
25 mat is often larger in size than in the binary format. Binary cursors
26 return the data in a binary representation that may be more easily
27 manipulated. Nevertheless, if you intend to display the data as text
28 anyway, retrieving it in text form will save you some effort on the
29 client side.
30
31 As an example, if a query returns a value of one from an integer col‐
32 umn, you would get a string of 1 with a default cursor whereas with a
33 binary cursor you would get a 4-byte field containing the internal rep‐
34 resentation of the value (in big-endian byte order).
35
36 Binary cursors should be used carefully. Many applications, including
37 psql, are not prepared to handle binary cursors and expect data to come
38 back in the text format.
39
40 Note: When the client application uses the ``extended query''
41 protocol to issue a FETCH command, the Bind protocol message
42 specifies whether data is to be retrieved in text or binary for‐
43 mat. This choice overrides the way that the cursor is defined.
44 The concept of a binary cursor as such is thus obsolete when
45 using extended query protocol — any cursor can be treated as
46 either text or binary.
47
48
50 name The name of the cursor to be created.
51
52 BINARY Causes the cursor to return data in binary rather than in text
53 format.
54
55 INSENSITIVE
56 Indicates that data retrieved from the cursor should be unaf‐
57 fected by updates to the tables underlying the cursor while the
58 cursor exists. In PostgreSQL, all cursors are insensitive; this
59 key word currently has no effect and is present for compatibil‐
60 ity with the SQL standard.
61
62 SCROLL
63
64 NO SCROLL
65 SCROLL specifies that the cursor may be used to retrieve rows in
66 a nonsequential fashion (e.g., backward). Depending upon the
67 complexity of the query's execution plan, specifying SCROLL may
68 impose a performance penalty on the query's execution time. NO
69 SCROLL specifies that the cursor cannot be used to retrieve rows
70 in a nonsequential fashion. The default is to allow scrolling in
71 some cases; this is not the same as specifying SCROLL. See Notes
72 [declare(7)] for details.
73
74 WITH HOLD
75
76 WITHOUT HOLD
77 WITH HOLD specifies that the cursor may continue to be used
78 after the transaction that created it successfully commits.
79 WITHOUT HOLD specifies that the cursor cannot be used outside of
80 the transaction that created it. If neither WITHOUT HOLD nor
81 WITH HOLD is specified, WITHOUT HOLD is the default.
82
83 query A SELECT [select(7)] or VALUES [values(7)] command which will
84 provide the rows to be returned by the cursor.
85
86 FOR READ ONLY
87
88 FOR UPDATE
89 FOR READ ONLY indicates that the cursor will be used in a read-
90 only mode. FOR UPDATE indicates that the cursor will be used to
91 update tables. Since cursor updates are not currently supported
92 in PostgreSQL, specifying FOR UPDATE will cause an error message
93 and specifying FOR READ ONLY has no effect.
94
95 column Column(s) to be updated by the cursor. Since cursor updates are
96 not currently supported in PostgreSQL, the FOR UPDATE clause
97 provokes an error message.
98
99 The key words BINARY, INSENSITIVE, and SCROLL may appear in any order.
100
102 Unless WITH HOLD is specified, the cursor created by this command can
103 only be used within the current transaction. Thus, DECLARE without WITH
104 HOLD is useless outside a transaction block: the cursor would survive
105 only to the completion of the statement. Therefore PostgreSQL reports
106 an error if this command is used outside a transaction block. Use
107 BEGIN [begin(7)], COMMIT [commit(7)] and ROLLBACK [rollback(7)] to
108 define a transaction block.
109
110 If WITH HOLD is specified and the transaction that created the cursor
111 successfully commits, the cursor can continue to be accessed by subse‐
112 quent transactions in the same session. (But if the creating transac‐
113 tion is aborted, the cursor is removed.) A cursor created with WITH
114 HOLD is closed when an explicit CLOSE command is issued on it, or the
115 session ends. In the current implementation, the rows represented by a
116 held cursor are copied into a temporary file or memory area so that
117 they remain available for subsequent transactions.
118
119 The SCROLL option should be specified when defining a cursor that will
120 be used to fetch backwards. This is required by the SQL standard. How‐
121 ever, for compatibility with earlier versions, PostgreSQL will allow
122 backward fetches without SCROLL, if the cursor's query plan is simple
123 enough that no extra overhead is needed to support it. However, appli‐
124 cation developers are advised not to rely on using backward fetches
125 from a cursor that has not been created with SCROLL. If NO SCROLL is
126 specified, then backward fetches are disallowed in any case.
127
128 The SQL standard only makes provisions for cursors in embedded SQL. The
129 PostgreSQL server does not implement an OPEN statement for cursors; a
130 cursor is considered to be open when it is declared. However, ECPG,
131 the embedded SQL preprocessor for PostgreSQL, supports the standard SQL
132 cursor conventions, including those involving DECLARE and OPEN state‐
133 ments.
134
135 You can see all available cursors by querying the pg_cursors system
136 view.
137
139 To declare a cursor:
140
141 DECLARE liahona CURSOR FOR SELECT * FROM films;
142
143 See FETCH [fetch(7)] for more examples of cursor usage.
144
146 The SQL standard allows cursors only in embedded SQL and in modules.
147 PostgreSQL permits cursors to be used interactively.
148
149 The SQL standard allows cursors to update table data. All PostgreSQL
150 cursors are read only.
151
152 Binary cursors are a PostgreSQL extension.
153
155 CLOSE [close(7)], FETCH [fetch(l)], MOVE [move(l)]
156
157
158
159SQL - Language Statements 2008-06-08 DECLARE()