Cursor Functions
Recall that cursors are one way to loop through records within a table (or several tables joined together) and perform a certain action on each affected record. SQL Server supports three functions that can help you while working with cursors: @@FETCH_STATUS, @@CURSOR_ROWS, and CURSOR_STATUS. Cursor functions are non-deterministic.
In order to understand how cursor functions work, you must first be familiar with the cursor's life cycle. Although there is not room to go into a detailed discussion of cursors, the typical cursor life cycle is as follows:
The cursor is declared using the DECLARE CURSOR statementthis simply creates a cursor within SQL Server memory.
The cursor is OPENEDat this point, you can start populating the cursor with rows. (However, the cursor doesn't have any data yet.)
The cursor is populated by using the FETCH keyword.
A WHILE loop is executed within the cursor to do some work with the rows in the cursor, with the condition that FETCH command is successful.
The cursor is CLOSED. At this point, you can't populate the cursor with additional rows, nor can you work with rows within the cursor. However, you can reopen the cursor with the OPEN keyword and perform additional work with the cursor.
Finally, the cursor is DEALLOCATED. At this point, the cursor representation is destroyed and the cursor cannot be resurrected.
If you don't know much about cursors or if you need a refresher, please refer to the SQL Server online documentation for details.
@@FETCH_STATUS
The most commonly used cursor function is @@FETCH_STATUS. This function determines whether FETCH keyword has successfully moved to a row within the cursor.
NOTE
Note: Typically, the FETCH command is used to move to the next row, but that is not always the case. You can use FETCH to move to the previous row or to a particular row within the cursor. Please refer to the SQL Server online documentation for more information about the syntax of FETCH [NEXT, PRIOR, ABSOLUTE, RELATIVE].
@@FETCH_STATUS can take one of the following three values:
@@FETCH_STATUS Value |
Meaning |
0 |
A successful fetch of a row within a cursor |
-1 |
FETCH has failed, which can mean that we're at the beginning (or end) or the set of records within the cursor. Alternatively, this can also mean that we attempted grabbing a record that does not exist. For instance, if you attempt to grab the one-hundredth record within a cursor that has 40 records, the FETCH status will be 1. |
-2 |
The fetched row is missing, which means that the record you're trying to fetch has been deleted or its key has been updated since you opened the cursor. |
For example, the following cursor returns the names of authors with the last name of Ringer. Although the cursor fetches rows successfully, the @@FETCH_STATUS is 0. Once we get to the end of the result set, @@FETCH_STATUS becomes 1:
SET NOCOUNT ON DECLARE @last_name VARCHAR(20), @first_name VARCHAR(20) DECLARE my_cursor CURSOR STATIC FOR SELECT au_lname, au_fname FROM authors WHERE au_lname = 'ringer' OPEN my_cursor FETCH NEXT FROM my_cursor INTO @last_name, @first_name WHILE @@FETCH_STATUS = 0 BEGIN SELECT @last_name, @first_name FETCH NEXT FROM my_cursor INTO @last_name, @first_name SELECT 'fetch status is ' + CAST(@@FETCH_STATUS AS VARCHAR) END CLOSE my_cursor DEALLOCATE my_cursor
Results:
-------------------- -------------------- Ringer Albert ---------------------------------------------- fetch status is 0 -------------------- -------------------- Ringer Anne ---------------------------------------------- fetch status is -1
@@CURSOR_ROWS
The @@CURSOR_ROWS function returns the number of rows in the cursor that was opened last on the current connection. This means that if you have three cursors open, @@CURSOR_ROWS will return the number of rows in the third cursor. @@CURSOR_ROWS can take the following values:
@@CURSOR_ROWS value |
Meaning |
-m |
Cursor is being populated asynchronously. Please refer to the SQL Server online documentation for more information on asynchronous population of cursors. "m" is the value of records in the keyset. |
-1 |
The cursor is DYNAMIC; in other words, it reflects the changes to the data within the cursor. Therefore, the number of rows can change due to the addition or deletion of rows in the underlying tables. DYNAMIC cursors always return 1 as value of @@CURSOR_ROWS. |
0 |
This can mean one of the following:
|
N |
The number of rows in the cursor. |
The following example shows you how the @@CURSOR_ROWS value changes during the lifetime of the cursor:
SET NOCOUNT ON DECLARE @last_name VARCHAR(20), @first_name VARCHAR(20) DECLARE my_cursor CURSOR STATIC FOR SELECT au_lname, au_fname FROM authors WHERE au_lname = 'ringer' SELECT 'cursor has ' + CAST(@@CURSOR_ROWS AS VARCHAR) + ' rows' OPEN my_cursor FETCH NEXT FROM my_cursor INTO @last_name, @first_name SELECT 'cursor has ' + CAST(@@CURSOR_ROWS AS VARCHAR) + ' rows' WHILE @@FETCH_STATUS = 0 BEGIN SELECT @last_name, @first_name FETCH NEXT FROM my_cursor INTO @last_name, @first_name END CLOSE my_cursor SELECT 'cursor has ' + CAST(@@CURSOR_ROWS AS VARCHAR) + ' rows' DEALLOCATE my_cursor
Results:
---------------------------------------------- cursor has 0 rows ---------------------------------------------- cursor has 2 rows -------------------- -------------------- Ringer Albert -------------------- -------------------- Ringer Anne ---------------------------------------------- cursor has 0 rows
CURSOR_STATUS
The CURSOR_STATUS function can be used effectively with stored procedures that call another procedure, which returns an output parameter with the CURSOR data type. In SQL Server 2000, you can return an output parameter with the CURSOR data type, which can be further manipulated by the calling routine. In order to use the CURSOR data type as an output parameter, you must specify the VARYING keyword along with OUTPUT within the CREATE PROCEDURE statement. The following example creates a procedure that returns a cursor as an output parameter:
CREATE PROCEDURE return_author_names ( @last_name VARCHAR(20), @my_cursor CURSOR VARYING OUTPUT ) AS BEGIN SET NOCOUNT ON SET @my_cursor = CURSOR STATIC FOR SELECT au_lname, au_fname FROM authors WHERE au_lname = @last_name OPEN @my_cursor END
Next, you can call the procedure you just created with a particular last name. Then you can use the CURSOR_STATUS function to determine whether the cursor returned from the procedure contains any rows. Check out the following example:
/* declare variables used to call the procedure:*/ DECLARE @last_name VARCHAR(20), @first_name VARCHAR(20) SET @last_name = 'green' DECLARE @my_cursor CURSOR /* now call the procedure returning a cursor */ EXECUTE return_author_names @last_name, @my_cursor OUTPUT IF CURSOR_STATUS('variable', '@my_cursor') = 0 BEGIN PRINT 'no records found' RETURN END ELSE BEGIN FETCH NEXT FROM @my_cursor INTO @last_name, @first_name WHILE @@FETCH_STATUS = 0 BEGIN SELECT @last_name, @first_name FETCH NEXT FROM @my_cursor INTO @last_name, @first_name END CLOSE @my_cursor DEALLOCATE @my_cursor END
Results:
-------------------- -------------------- Green Marjorie
Now, if you replace the last name of "Green" with something that is not found in the authors' table (try "Brown"), you will get the following output:
no records found
As mentioned earlier, the CURSOR_STATUS is effective when one procedure calls another, which returns a CURSOR data type. However, CURSOR_STATUS can also be used with local or global cursors, as in the following example:
SET NOCOUNT ON DECLARE @last_name VARCHAR(20), @first_name VARCHAR(20) DECLARE my_cursor CURSOR GLOBAL FOR SELECT au_lname, au_fname FROM authors WHERE au_lname = 'green' OPEN my_cursor FETCH NEXT FROM my_cursor INTO @last_name, @first_name WHILE @@FETCH_STATUS = 0 BEGIN SELECT @last_name, @first_name FETCH NEXT FROM my_cursor INTO @last_name, @first_name END SELECT 'cursor status is: ' + CAST(CURSOR_STATUS('global', 'my_cursor') AS VARCHAR) CLOSE my_cursor SELECT 'cursor status is: ' + CAST(CURSOR_STATUS('global', 'my_cursor') AS VARCHAR) DEALLOCATE my_cursor
Results:
-------------------- -------------------- Green Marjorie ------------------------------------------------ cursor status is: 1 ------------------------------------------------ cursor status is: -1
The following table summarizes the values returned by the CURSOR_STATUS function:
CURSOR_STATUS Value |
Meaning for Variable |
Meaning for Cursor Name |
1 |
Cursor is open and has at least one row. * DYNAMIC cursors might have 0 rows and still return 1. |
Cursor is open and has at least one row. * DYNAMIC cursors might have 0 rows and still return 1. |
0 |
Cursor is open, but has no rows. |
Cursor has no rows. |
-1 |
Cursor is closed |
Cursor is closed |
-2 |
Cursor wasn't returned by the called procedure or the cursor was deallocated prior to being assigned to this variable. |
The value of 2 is not returned by the CURSOR_STATUS if you refer to the cursor name. |
-3 |
Cursor variable with that name does not exist or the variable exists, but it hasn't been assigned to a cursor returned from the called procedure. |
Cursor with the specified name does not exist. |