DECLARE SQL - Language Statements DECLARE define a cursor 1999-07-20 DECLARE cursorname [ BINARY ] [ INSENSITIVE ] [ [ NO ] SCROLL ] CURSOR [ { WITH | WITHOUT } HOLD ] FOR query [ FOR { READ ONLY | UPDATE [ OF column [, ...] ] ] 1998-04-15 Inputs cursorname The name of the cursor to be used in subsequent FETCH operations. BINARY Causes the cursor to return data in binary rather than in text format. INSENSITIVE SQL92 keyword indicating that data retrieved from the cursor should be unaffected by updates from other processes or cursors. By default, all cursors are insensitive. This keyword currently has no effect and is present for compatibility with the SQL standard. NO SCROLL Specifies that the cursor cannot be used to retrieve rows in a nonsequential fashion (e.g., backward). SCROLL Specifies that the cursor may be used to retrieve rows in a nonsequential fashion (e.g., backward). Depending upon the complexity of the query's execution plan, specifying SCROLL may impose a slight performance penalty on the query's execution time. WITHOUT HOLD Specifies that the cursor cannot be used outside of the transaction that created it. If neither WITHOUT HOLD nor WITH HOLD is specified, WITH HOLD is the default. WITH HOLD Specifies that the cursor may be used after the transaction that creates it successfully commits. query A SELECT query which will provide the rows to be returned by the cursor. Refer to for further information about valid arguments. READ ONLY SQL92 keyword indicating that the cursor will be used in a read only mode. Since this is the only cursor access mode available in PostgreSQL this keyword has no effect. UPDATE SQL92 keyword indicating that the cursor will be used to update tables. Since cursor updates are not currently supported in PostgreSQL this keyword provokes an informational error message. column Column(s) to be updated. Since cursor updates are not currently supported in PostgreSQL the UPDATE clause provokes an informational error message. The BINARY, INSENSITIVE, SCROLL keywords may appear in any order. 1998-04-15 Outputs DECLARE CURSOR The message returned if the SELECT is run successfully. WARNING: Closing pre-existing portal "cursorname" This message is reported if a cursor with the same name already exists. The previous definition is discarded. ERROR: DECLARE CURSOR may only be used in begin/end transaction blocks This error occurs if the cursor is not declared within a transaction block, and WITH HOLD is not specified. 1998-09-04 Description DECLARE 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. Cursors can return data either in text or in binary format using . Normal cursors return data in text format, the same as a SELECT would produce. Since data is stored natively in binary format, the system must do a conversion to produce the text format. In addition, text formats are often larger in size than the corresponding binary format. Once the information comes back in text form, the client application may need to convert it to a binary format to manipulate it. BINARY cursors give you back the data in the native binary representation. As an example, if a query returns a value of one from an integer column, you would get a string of 1 with a default cursor whereas with a binary cursor you would get a 4-byte value equal to control-A (^A). BINARY cursors should be used carefully. User applications such as psql are not aware of binary cursors and expect data to come back in a text format. String representation is architecture-neutral whereas binary representation can differ between different machine architectures. PostgreSQL does not resolve byte ordering or representation issues for binary cursors. Therefore, if your client machine and server machine use different representations (e.g., big-endian versus little-endian), you will probably not want your data returned in binary format. If you intend to display the data as text, retrieving it in text form will save you some effort on the client side. 1998-09-04 Notes If WITH HOLD is not specified, the cursor created by this command can only be used within the current transaction. Use , and to define a transaction block. If WITH HOLD is specified and the transaction that created the cursor successfully commits, the cursor can be accessed outside the creating transaction. If the creating transaction is aborted, the cursor is removed. A cursor created with WITH HOLD is closed when an explicit CLOSE command is issued on it, or the client connection is terminated. The SCROLL option should be specified when defining a cursor that will be used to fetch backwards. This is required by SQL92. However, for compatibility with earlier versions, PostgreSQL will allow backward fetches without 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 SCROLL. In SQL92 cursors are only available in embedded SQL (ESQL) applications. The PostgreSQL backend does not implement an explicit OPEN cursor statement; a cursor is considered to be open when it is declared. However, ecpg, the embedded SQL preprocessor for PostgreSQL, supports the SQL92 cursor conventions, including those involving DECLARE and OPEN statements. Usage To declare a cursor: DECLARE liahona CURSOR FOR SELECT * FROM films; Compatibility 1998-04-15 SQL92 SQL92 allows cursors only in embedded SQL and in modules. PostgreSQL permits cursors to be used interactively. SQL92 allows embedded or modular cursors to update database information. All PostgreSQL cursors are read only. The BINARY keyword is a PostgreSQL extension.