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.