DB2 SQL Procedural Language: Using Flow of Control Statements
In this chapter, you will learn:
how to use the compound statement;
how to use labels in both compound statements and loops;
how to use the two conditional statements (IF and CASE);
how to use the four looping statements (FOR, WHILE, REPEAT, and LOOP);
how to use the four transfer of control statements (GOTO, LEAVE, ITERATE and RETURN).
Sequential execution is the most basic path that program execution can take. With this method, the program starts execution at the first line of the code, followed by the next, and continues until the final statement in the code has been executed. This approach works fine for very simple tasks but tends to lack usefulness since it can only handle one situation. Like humans, most programs need to be able to decide what to do in response to changing circumstances. By controlling a code's execution path, a specific piece of code can then be used to handle intelligently more than one situation.
Flow of control statements are used to control the sequence of statement execution. Statements such as IF and CASE are used to conditionally execute blocks of SQL Procedural Language (SQL PL) statements, while other statements, such as WHILE and REPEAT, are typically used to execute a set of statements repetitively until a task is complete.
Although there are many flow of control statements to be discussed in this chapter, there are three main categories: conditional statements, loop statements, and transfer of control statements. Before jumping into a discussion on flow of control statements, it is important to first understand the use of compound statements.
3.1 Compound Statements
Of all the SQL control statements, the compound statement is the easiest to work with and understand. Compound statements are used to group together a set of related lines of code. You can declare variables, cursors, and condition handlers and use flow of control statements within a compound statement (cursors and condition handlers are discussed in later chapters).
BEGIN and END are keywords that define a compound statement. The BEGIN keyword defines the starting line of code for the compound statement, while the END keyword defines the final line of code. Compound statements are used to control variable scoping and for executing more than a single statement where a single statement is expected (such as within a condition handler, which will be discussed in Chapter 5, "Condition Handling").
Each compound statement has its own scope, where only variables and the like that have been declared within the same compound statement or within enclosing compound statements can be seen. That is, statements within one compound statement may not be able to refer to variables and values that are declared within another compound statement, even if both compound statements are part of the same SQL procedure body.
It is perfectly logical and, in most cases, completely valid to have the ability to define as many compound statements as needed within an SQL procedure (see ATOMIC for the exception). These compound statements are typically used to introduce scoping and a logical separation of related statements.
There is a specific order for declaring variables, conditions, cursors and handlers within a compound statement. Specifically, the order of declarations must proceed as follows:
BEGIN variable declarations condition declarations cursor declarations handler declarations assignment, flow of control, SQL statements, and other compound statements END
Don't worry if you are not familiar with some of the above terms, as they will be discussed in greater detail later. Also, notice that one or several compound statements can be nested within other compound statements. In such cases, the same order of declarations continues to apply at each level.
It is important to understand the type of variable scoping (or visibility) that occurs when a compound statement has been defined. Specifically:
Outer compound statements cannot see variables declared within inner compound statements.
Inner compound statements can see variables that have been declared in outer compound statements.
Scoping is illustrated in Figure 3.1.
Figure 3.1 Variable Scoping Example
BEGIN -- (1) DECLARE v_outer1 INT; DECLARE v_outer2 INT; BEGIN -- (2) DECLARE v_inner1 INT; DECLARE v_inner2 INT; SET v_outer1 = 100; -- (3) SET v_inner1 = 200; -- (4) END; -- (5) SET v_outer2 = 300; -- (6) SET v_inner2 = 400; -- (7) END -- (8)
In the above, (1) and (8) define the outer compound statement, while (2) and (5) define the inner compound statement. All statements, except statement (7), will succeed. Statement (7) fails because an outer compound statement cannot see a variable declared within an inner compound statement. You will receive an SQLSTATE 42703 error with the message "'V_INNER2' is not valid in the context where it is used."
Scoping can be especially useful in the case of looping and exception handling, allowing the program flow to jump from one compound statement to another.
There are two distinct types of compound statements, which both serve a different purpose.
3.1.1 NOT ATOMIC Compound Statement
The previous example illustrated a NOT ATOMIC compound statement and is the default type used in SQL procedures. If an unhandled error (that is, no condition handler has been declared for the SQLSTATE raised) occurs within the compound statement, any work which is completed before the error will not be rolled back, but will not be committed either. The group of statements can only be rolled back if the unit of work is explicitly rolled back using ROLLBACK or ROLLBACK TO SAVEPOINT (the latter is discussed in Chapter 8, "Advanced Features"). You can also COMMIT successful statements if it makes sense to do so.
The syntax to for a NOT ATOMIC compound statement is shown in Figure 3.2.
Figure 3.2 NOT ATOMIC Compound Statement Syntax Diagram
.-NOT ATOMIC--. >>-+---------+--BEGIN----+-------------+------------------------> '-label:--' ... Misc. Statements; ... >-------------------------------------+---END--+--------+------>< '-label--'
The optional label is used to define a name for the code block. The label can be used to qualify SQL variables declared within the compound statement. If the ending label is used, it must be the same as the beginning label. We will learn more about labels later in this chapter.
The use of the NOT ATOMIC keywords is optional, but usually suggested, as it reduces ambiguity of the code.
The SQL procedure illustrated in Figure 3.3 demonstrates the non-atomicity of NOT ATOMIC compound statements:
Figure 3.3 NOT ATOMIC Compound Statement Example
CREATE PROCEDURE not_atomic_proc () SPECIFIC not_atomic_proc LANGUAGE SQL BEGIN NOT ATOMIC -- Declare variables DECLARE v_job VARCHAR(8); -- Procedure logic INSERT INTO atomic_test(proc, res) VALUES ('Not_Atomic_Proc','Before error test'); SIGNAL SQLSTATE '70000'; -- (1) INSERT INTO atomic_test(proc, res) VALUES ('Not_Atomic_Proc','After error test'); END
Right now, it is sufficient to understand that the SIGNAL statement at (1) is used to explicitly raise an error. Additionally, since this error is unhandled, the procedure will exit right after the error.
After calling this procedure, you will see that although an error has been raised halfway through execution, the first INSERT successfully inserted a row into the atomic_test table. It has not been committed or rolled back, however.
3.1.2 ATOMIC Compound Statement
The ATOMIC compound statement, as the name suggests, can be thought of as a singular wholeif any unhandled error conditions arise within it, all statements which have been executed up to that point are considered to have failed as well and are therefore rolled back. ATOMIC compound statements cannot be nested inside other ATOMIC compound statements.
In addition, you cannot use SAVEPOINTs or issue explicit COMMITs or ROLLBACKs from within an ATOMIC compound statement.
NOTE
COMMIT, ROLLBACK, SAVEPOINTS and nested ATOMIC compound statements are not allowed within an ATOMIC compound statement.
The syntax to declare an ATOMIC compound statement is shown in Figure 3.4.
Figure 3.4 ATOMIC Compound Statement Syntax Diagram
>>-+---------+--BEGIN ATOMIC------------------------------------> '-label:--' ... Misc. Statements; ... >-------------------------------------+---END--+--------+------>< '-label--'
A label is used in the same way as with a NOT ATOMIC compound statement.
The example in Figure 3.5 illustrates the behavior of an ATOMIC compound statement. It is quite similar to the NOT ATOMIC example above, and only differs in name and the fact that it uses an ATOMIC compound statement.
Figure 3.5 ATOMIC Compound Statement Example
CREATE PROCEDURE atomic_proc () SPECIFIC atomic_proc LANGUAGE SQL BEGIN ATOMIC -- Declare variables DECLARE v_job VARCHAR(8); -- Procedure logic INSERT INTO atomic_test(proc, res) VALUES ('Atomic_Proc','Before error test'); SIGNAL SQLSTATE '70000'; -- (1) INSERT INTO atomic_test(proc, res) VALUES ('Atomic_Proc','After error test'); END
When the error condition of SQLSTATE 70000 is raised at (1), the unhandled error causes procedure execution to stop. Unlike the NOT ATOMIC example in Figure 3.3, the first INSERT statement will be rolled back, resulting in a table with no inserted rows from this procedure.