Home > Articles > Data > DB2

This chapter is from the book

3.4 Looping Statements

Loops allow you to execute a set of statements repeatedly until a certain condition is reached. The loop terminating condition may be defined at the beginning, in the middle, or at the end of the loop using the WHILE, LOOP, and REPEAT statements, respectively. Also, a FOR loop is available for iterating over a read-only result set and its terminating condition is when no more rows are left to read. Once the loop terminating condition has been met, looping ceases and the flow of control continues on the line directly following the loop. Variables cannot be declared within loops.

For readability, it is best to indent the loop body relative to the loop statement.

The WHILE and REPEAT loops are typically used when you do not know how many times to iterate through the loop prior to entering it. You should use the WHILE loop when you may not want to execute the loop even once, and the REPEAT loop when you want to ensure that the statements within the loop are executed at least once. The FOR loop is used for situations where you need to iterate over a read-only result set, using result set values for some purpose such as defining the value of a variable. LOOP is generally used for all other cases.

3.4.1 FOR Loop

The FOR loop is used to iterate over a read-only result set that is defined by its select-statement. Looping will cease when there are no rows left in the result set. Positioned updates and deletes are not supported in the FOR loop. However, searched updates and deletes are allowed.

The syntax is depicted in Figure 3.12.

Figure 3.12 FOR Statement Syntax Diagram

>>-+---------+---FOR--for-loop-name--AS-------------------------> 
   '-label:--' 

>-----+--------------------------+--select-statement---DO------->
      '-cursor-name--CURSOR FOR--' 

      .-------------------------------. 
      V                               | 
>--------SQL-procedure-statement--;---+--END FOR----+--------+-><
                                                    '-label--'

The for-loop-name specifies a label for the implicit compound statement generated to implement the FOR statement. It follows the rules for the label of a compound statement except that it cannot be used with ITERATE or LEAVE (which are described later). The for-loop-name can be used to qualify the column names in the result set as returned by the select-statement.

The cursor-name simply names the cursor that is used to select rows from the result set. If not specified, DB2 will automatically generate a unique cursor name internally.

The column names of the select-statement must be unique and a FROM clause specifying a table (or multiple tables if doing some kind of JOIN or UNION) is required. The table(s) and column(s) referenced must exist prior to the loop being executed. This allows you to iterate over result sets that are formed from tables that exist prior to invoking the stored procedure, or tables that have been created by a previous SQL PL statement (such as declared user-temporary tables, which are discussed in Chapter 8, "Advanced Features").

The FOR loop is essentially a CURSOR defined by the select-statement. This CURSOR cannot be referenced outside of the FOR loop, however, so OPEN, FETCH, and CLOSE statements will result in error.

In Figure 3.13, the FOR loop is used to iterate over all rows of the employee table (since no WHERE clause is being used).

Figure 3.13 FOR Loop Example

FOR v_row AS SELECT firstnme, midinit, lastname	                               -- (1)
    FROM employee	 	 
    DO	 	 	 
        SET v_fullname = v_row.lastname || ', ' || v_row.firstnme || ' ' ||	 
 	        v_row.midinit;	                                               -- (2)
    INSERT INTO tname VALUES (v_fullname);	                               -- (3)
END FOR	 	 	 

You can see the defining select-statement at (1) and where the columns of the result set are being concatenated together to form the v_fullname at (2). Finally, this newly formed v_fullname is inserted into a table called tname at (3).

3.4.2 WHILE Loop

The defining feature of a WHILE loop is that its looping condition is evaluated prior to initial loop execution and all following loop iterations. The WHILE loop will continue to execute until the looping condition evaluates to false. Be sure not to define a condition that always evaluates to true, or you will get caught in an infinite loop.

When defining the looping condition, be sure to specify a full conditional statement (which includes operators). Otherwise, your SQL procedure will not build. For example:

WHILE (variable) DO statement1; statement2; END WHILE; 

is not enough. You need to use an operator, as in:

WHILE (variable = 1) DO statement1; statement2; END WHILE; 

The syntax for the WHILE loop is illustrated in Figure 3.14.

Figure 3.14 WHILE Loop Syntax Diagram

>>-+---------+--WHILE--search-condition--DO---------------------> 
   '-:label--' 

      .-------------------------------. 
      V                               | 
>--------SQL-procedure-statement--;---+--END WHILE--------------> 

>-----+--------+----------------------------------------------->< 
      '-label--'

The search-condition specifies a condition that is evaluated before each execution of the loop. If the condition is true, the SQL-procedure-statements in the loop are processed.

Figure 3.15 illustrates how to use a WHILE loop to sum all integer values between n and m (which are assumed to be positive and provided by input parameters to the procedure).

Figure 3.15 Simple WHILE Loop Example

CREATE PROCEDURE sum_mn (IN p_start INT 
                        ,IN p_end INT 
                        ,OUT p_sum INT) 
SPECIFIC sum_mn 
LANGUAGE SQL 
smn: BEGIN 
   DECLARE v_temp INTEGER DEFAULT 0; 
   DECLARE v_current INTEGER; 
   SET v_current = p_start; 


   WHILE (v_current <= p_end) DO 
       SET v_temp = v_temp + v_current; 
       SET v_current = v_current + 1; 
   END WHILE; 

   SET p_sum = v_temp; 

END smn 

The above example is fairly simple and is intended to show you how the WHILE loop works using as little code as possible. More commonly, however, a WHILE loop is used to repeatedly perform SQL procedure statements, such as FETCH (for retrieving row values from a cursor). For examples of using WHILE loops with cursor operations such as OPEN, FETCH and CLOSE, see Chapter 4, "Understanding and Using Cursors and Result Sets."

3.4.3 REPEAT

In the WHILE loop, you saw that the looping condition is evaluated at the very beginning of the loop. If the looping condition evaluates to false at this first examination, then the loop body will not execute at all.

In some cases, however, it may be necessary that the loop be executed at least once.

This is where the REPEAT loop is useful. A REPEAT loop ensures that at least one iteration of the loop is completed. This is the case because the looping condition is not evaluated until the final line of code in the loop.

The syntax for the REPEAT loop is shown in Figure 3.16.

Figure 3.16 REPEAT Loop Syntax Diagram

                          .-------------------------------.
                          V                               | 
>>-+---------+--REPEAT-------SQL-procedure-statement--;---+----->
   '-label:--' 

>----UNTIL--search-condition---END REPEAT----+--------+--------><
                                             '-label--' 

In Figure 3.17, the procedure from Figure 3.15 is re-implemented using REPEAT.

Figure 3.17 REPEAT Loop Example

CREATE PROCEDURE sum_mn2 (IN p_start INT 
                         ,IN p_end INT 
                         ,OUT p_sum INT) 
SPECIFIC sum_mn2 
LANGUAGE SQL 
smn2: BEGIN 
   DECLARE v_temp INTEGER DEFAULT 0; 
   DECLARE v_current INTEGER; 


   SET v_current = p_start; 


   REPEAT 
       SET v_temp = v_temp + v_current; 
       SET v_current = v_current + 1; 
   UNTIL (v_current > p_end) 
   END REPEAT; 

   SET p_sum = v_temp; 

END smn2 

3.4.4 LOOP

The LOOP statement is somewhat different from the other types of loops that we have looked at thus far. The LOOP does not have a terminating condition clause that is part of its declaration statement. It will continue to loop until some other piece of code inside it explicitly forces the flow of control to jump to some point outside of the loop.

LOOP will commonly have some logic that eventually branches to a LEAVE statement. You can also use a GOTO statement instead of a LEAVE, but the use of GOTO is discouraged. Ensure that some action within the loop eventually invokes a LEAVE or GOTO statement. Otherwise, your code can get caught in an infinite loop.

The LOOP syntax is illustrated in Figure 3.18.

Figure 3.18 LOOP Syntax Diagram

                        .-------------------------------. 
                        V                               | 
>>-+---------+--LOOP-------SQL-procedure-statement--;---+------->
   '-label:--' 

>----END LOOP----+--------+------------------------------------>< 
                 '-label--' 

There is no terminating condition defined within the LOOP syntax itself.

An example of using LOOP is deferred until the discussion on LEAVE in the next section.

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