A compound statement groups other statements together in an SQL procedure. A compound statement allows the declaration of SQL variables, cursors, and condition handlers.
.-NOT ATOMIC-. >>-+--------+--BEGIN--+------------+----------------------------> '-label:-' '-ATOMIC-----' >--+--------------------------------------+---------------------> | .----------------------------------. | | V | | '---+-SQL-variable-declaration-+-- ;-+-' +-condition-declaration----+ '-return-codes-declaration-' >--+----------------------------------+-------------------------> | .------------------------------. | | V | | '---DECLARE CURSOR-statement-- ;-+-' >--+-----------------------------+------------------------------> | .-------------------------. | | V | | '---handler-declaration-- ;-+-' .---------------------------------. V | >----+-----------------------------+-+--END--+-------+--------->< '-SQL-procedure-statement-- ;-' '-label-' SQL-variable-declaration: .-,-----------------. V | |--DECLARE----SQL-variable-name-+-------------------------------> .-DEFAULT NULL-------------------------. >--data-type--+--------------------------------------+----------| '-DEFAULT--constant--+---------------+-' | (1) | '-NOT NULL------' condition-declaration: |--DECLARE--SQL-condition-name----------------------------------> .-VALUE-. .-SQLSTATE--+-------+-. >--CONDITION--FOR--+---------------------+--string-constant-----| return-codes-declaration: |--DECLARE------------------------------------------------------> .-DEFAULT--'00000'---------. >--+-SQLSTATE--+-CHARACTER(5)-+--+--------------------------+-+--| | '-CHAR(5)------' '-DEFAULT--string-constant-' | | .-DEFAULT--0----------------. | '-SQLCODE--+-INTEGER-+--+---------------------------+------' '-INT-----' '-DEFAULT--integer-constant-' handler-declaration: |--DECLARE--+-CONTINUE-+--HANDLER FOR---------------------------> +-EXIT-----+ '-UNDO-----' (2) >--+-specific-condition-value-+-------SQL-procedure-statement---| '-general-condition-value--' specific-condition-value: .-,-------------------------------. V .-VALUE-. | |----+-SQLSTATE--+-------+--string-+-+--------------------------| '-condition-name--------------' general-condition-value: |--+-SQLEXCEPTION-+---------------------------------------------| +-SQLWARNING---+ '-NOT FOUND----' data-type: |--+-built-in-type------+---------------------------------------| '-distinct-type-name-'
built-in-type: |--+-+---SMALLINT---+-----------------------------------------------------------------+--| | +-+-INTEGER-+--+ | | | '-INT-----' | | | '---BIGINT-----' | | .-(--5,0--)--------------------. | +-+-+-DECIMAL-+-+--+------------------------------+--------------------------------+ | | '-DEC-----' | | .-,0--------. | | | '-NUMERIC-----' '-(--integer--+-----------+--)-' | | '-, integer-' | | .-(--53--)------. | +-+-FLOAT--+---------------+-+-----------------------------------------------------+ | | '-(--integer--)-' | | | +-REAL---------------------+ | | | .-PRECISION-. | | | '-DOUBLE--+-----------+----' | | .-(--1--)-------. | +-+-+-+-CHARACTER-+--+---------------+----------+--+----------------+------------+-+ | | | '-CHAR------' '-(--integer--)-' | +-FOR BIT DATA---+ | | | | '-+-+-CHARACTER-+--VARYING-+--(--integer--)-' +-FOR SBCS DATA--+ | | | | | '-CHAR------' | +-FOR MIXED DATA-+ | | | | '-VARCHAR----------------' '-CCSID--integer-' | | | | .-(--1M--)-------------. | | | '---+-CLOB-------------------+----+----------------------+--+----------------+-' | | +-CHAR LARGE OBJECT------+ '-(--integer--+---+--)-' +-FOR SBCS DATA--+ | | '-CHARACTER LARGE OBJECT-' +-K-+ +-FOR MIXED DATA-+ | | +-M-+ '-CCSID--integer-' | | '-G-' | | .-(--1--)-------. | +-+---GRAPHIC----+---------------+-------+--+----------------+---------------------+ | | '-(--integer--)-' | '-CCSID--integer-' | | +-+-GRAPHIC VARYING-+--(--integer--)---+ | | | '-VARGRAPHIC------' | | | | .-(--1M--)-------------. | | | '---DBCLOB----+----------------------+-' | | '-(--integer--+---+--)-' | | +-K-+ | | +-M-+ | | '-G-' | | .-(--1--)-------. | +-+-+-BINARY--+---------------+---------+-----------------+------------------------+ | | | '-(--integer--)-' | | | | | '-+-BINARY VARYING-+--(--integer--)-' | | | | '-VARBINARY------' | | | | .-(--1M--)-------------. | | | '---+-BLOB----------------+----+----------------------+-' | | '-BINARY LARGE OBJECT-' '-(--integer--+---+--)-' | | +-K-+ | | +-M-+ | | '-G-' | +-+-DATE------+--------------------------------------------------------------------+ | +-TIME------+ | | '-TIMESTAMP-' | | .-(--200--)-----. | +---DATALINK--+---------------+--+----------------+--------------------------------+ | '-(--integer--)-' '-CCSID--integer-' | '---ROWID--------------------------------------------------------------------------'
An SQL-variable-name can only be referenced within the compound-statement in which it is declared (including any compound-statements nested within the compound-statement).
If the data-type is a graphic string data type, consider specifying CCSID 1200 or 13488 to indicate UTF-16 or UCS-2 data. If a CCSID is not specified, the CCSID of the graphic string variable will be the associated DBCS CCSID for the job.
A condition-name can only be referenced within the compound-statement in which it is declared (including any compound-statements nested within the compound-statement).
Assignment to these variables is not prohibited. However, the assignment will not be useful since the next SQL statement will replace the assigned value. The SQLCODE and SQLSTATE variables cannot be set to NULL.
SQLCODE and SQLSTATE variables should be saved immediately to another SQL variable if there is any intention to use the values. If a handler exists for the SQLSTATE, this assignment must be the first statement in the handler to avoid having the value replaced by the next SQL procedure statement.
A cursor-name can only be referenced within the compound-statement in which it is declared (including any compound-statements nested within the compound-statement).
Use an OPEN statement to open the cursor, and a FETCH statement to read rows using the cursor. If the cursor in an SQL procedure and is intended for use as a result set:
Any open cursor that does not meet these criteria is closed at the end of the compound-statement.
For more information on declaring a cursor, refer to DECLARE CURSOR.
A handler is active for the set of SQL-procedure-statements that follow the handler-declarations within the compound-statement in which it is declared.
A handler for a condition may exist at several levels of nested compound statements. For example, assume that compound statement n1 contains another compound statement n2 which contains another compound statement n3. When an exception condition occurs within n3, any active handlers within n3 are first allowed to handle the condition. If no appropriate handler exists in n3, then the condition is resignalled to n2 and the active handlers within n2 may handle the condition. If no appropriate handler exists in n2, then the condition is resignalled to n1 and the active handlers within n1 may handle the condition. If no appropriate handler exists in n1, the condition is considered unhandled.
There are three types of condition handlers:
UNDO cannot be specified in the outermost compound-statement of an SQL function or SQL trigger.
The conditions under which the handler is activated are:
The same condition cannot be specified more than once in the handler-declaration.
If the SQL-procedure-statement specified in the handler is either a SIGNAL or RESIGNAL statement with an exception SQLSTATE, the compound-statement will exit with the specified exception even if this handler or another handler in the same compound-statement specifies CONTINUE, since these handlers are not in the scope of this exception. If the compound-statement is nested in another compound-statement, handlers in the higher level compound-statement may handle the exception because those handlers are within the scope of the exception.
Nesting compound statements: Compound statements can be nested. Nested compound statements can be used to scope handlers and cursors to a subset of the statements in a procedure. This can simplify the processing done for each SQL procedure statement.
Rules for handler-declaration:
Null values in SQL parameters and SQL variables: If the value of an SQL parameter or SQL variable is null and it is used in an SQL statement (such as CONNECT or DESCRIBE) that does not allow an indicator variable, an error is returned.
Create a procedure body with a compound statement that performs the following actions.
CREATE PROCEDURE DEPT_MEDIAN (IN deptNumber SMALLINT, OUT medianSalary DOUBLE) LANGUAGE SQL BEGIN DECLARE v_numRecords INTEGER DEFAULT 1; DECLARE v_counter INTEGER DEFAULT 0; DECLARE c1 CURSOR FOR SELECT salary FROM staff WHERE DEPT = deptNumber ORDER BY salary; DECLARE EXIT HANDLER FOR NOT FOUND SET medianSalary = 6666; /* initialize OUT parameter */ SET medianSalary = 0; SELECT COUNT(*) INTO v_numRecords FROM staff WHERE DEPT = deptNumber; OPEN c1; WHILE v_counter < (v_numRecords / 2 + 1) DO FETCH c1 INTO medianSalary; SET v_counter = v_counter + 1; END WHILE; CLOSE c1; END