Home > Articles > Data > SQL Server

Like this article? We recommend

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 statement—this simply creates a cursor within SQL Server memory.

  • The cursor is OPENED—at 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:

The cursor has not been opened.

The cursor has no rows.

The cursor has been closed.

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.


InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020