ibm-information-center/dist/eclipse/plugins/i5OS.ic.db2_5.4.0.1/rbafzmstcompoundstmt.htm

442 lines
28 KiB
HTML
Raw Normal View History

2024-04-02 14:02:31 +00:00
<?xml version="1.0" encoding="utf-8"?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN"
"http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd">
<html xmlns="http://www.w3.org/1999/xhtml" lang="en-US" xml:lang="en-us">
<head>
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
<meta name="dc.language" scheme="rfc1766" content="en-us" />
<!-- All rights reserved. Licensed Materials Property of IBM -->
<!-- US Government Users Restricted Rights -->
<!-- Use, duplication or disclosure restricted by -->
<!-- GSA ADP Schedule Contract with IBM Corp. -->
<meta name="dc.date" scheme="iso8601" content="2005-09-19" />
<meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" />
<meta name="security" content="public" />
<meta name="Robots" content="index,follow"/>
<meta http-equiv="PICS-Label" content='(PICS-1.1 "http://www.icra.org/ratingsv02.html" l gen true r (cz 1 lz 1 nz 1 oz 1 vz 1) "http://www.rsac.org/ratingsv01.html" l gen true r (n 0 s 0 v 0 l 0) "http://www.classify.org/safesurf/" l gen true r (SS~~000 1))' />
<meta name="keywords" content="compound-statement, SQL-control-statement,
SQL statements" />
<title>compound-statement</title>
<link rel="stylesheet" type="text/css" href="ibmidwb.css" />
<link rel="stylesheet" type="text/css" href="ic.css" />
</head>
<body>
<a id="Top_Of_Page" name="Top_Of_Page"></a><!-- Java sync-link -->
<script language = "Javascript" src = "../rzahg/synch.js" type="text/javascript"></script>
<a name="compoundstmt"></a>
<h2 id="compoundstmt"><a href="rbafzmst02.htm#ToC_1425">compound-statement</a></h2><a id="idx3339" name="idx3339"></a><a id="idx3340" name="idx3340"></a>
<p>A compound statement groups other statements together in an SQL procedure.
A compound statement allows the declaration of SQL variables, cursors, and
condition handlers.</p>
<a name="wq1863"></a>
<h3 id="wq1863"><a href="rbafzmst02.htm#ToC_1426">Syntax</a></h3>
<a href="rbafzmstcompoundstmt.htm#synccompound"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn410.htm"
border="0" /></span><a href="#skipsyn-409"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a> .-NOT ATOMIC-.
>>-+--------+--BEGIN--+------------+---------------------------->
'-<span class="italic">label:</span>-' '-ATOMIC-----'
>--+--------------------------------------+--------------------->
| .----------------------------------. |
| V | |
'---+-<span class="italic">SQL-variable-declaration</span>-+-- ;-+-'
+-<span class="italic">condition-declaration</span>----+
'-<span class="italic">return-codes-declaration</span>-'
>--+----------------------------------+------------------------->
| .------------------------------. |
| V | |
'---<span class="italic">DECLARE CURSOR-statement</span>-- ;-+-'
>--+-----------------------------+------------------------------>
| .-------------------------. |
| V | |
'---<span class="italic">handler-declaration</span>-- ;-+-'
.---------------------------------.
V |
>----+-----------------------------+-+--END--+-------+--------->&lt;
'-<span class="italic">SQL-procedure-statement</span>-- ;-' '-<span class="italic">label</span>-'
SQL-variable-declaration:
.-,-----------------.
V |
|--DECLARE----<span class="italic">SQL-variable-name</span>-+------------------------------->
.-DEFAULT NULL-------------------------.
>--<span class="italic">data-type</span>--+--------------------------------------+----------|
'-DEFAULT--<span class="italic">constant</span>--+---------------+-'
| (1) |
'-NOT NULL------'
condition-declaration:
|--DECLARE--<span><span class="italic">SQL-condition-name</span></span>---------------------------------->
.-VALUE-.
.-SQLSTATE--+-------+-.
>--CONDITION--FOR--+---------------------+--<span class="italic">string-constant</span>-----|
return-codes-declaration:
|--DECLARE------------------------------------------------------>
.-DEFAULT--'00000'---------.
>--+-SQLSTATE--+-CHARACTER(5)-+--+--------------------------+-+--|
| '-CHAR(5)------' '-DEFAULT--<span class="italic">string-constant</span>-' |
| .-DEFAULT--0----------------. |
'-SQLCODE--+-INTEGER-+--+---------------------------+------'
'-INT-----' '-DEFAULT--<span class="italic">integer-constant</span>-'
handler-declaration:
|--DECLARE--+-CONTINUE-+--HANDLER FOR--------------------------->
+-EXIT-----+
'-UNDO-----'
(2)
>--+-<span class="italic">specific-condition-value</span>-+-------<span class="italic">SQL-procedure-statement</span>---|
'-<span class="italic">general-condition-value</span>--'
specific-condition-value:
.-,-------------------------------.
V .-VALUE-. |
|----+-SQLSTATE--+-------+--<span class="italic">string</span>-+-+--------------------------|
'-<span class="italic">condition-name</span>--------------'
general-condition-value:
|--+-SQLEXCEPTION-+---------------------------------------------|
+-SQLWARNING---+
'-NOT FOUND----'
data-type:
|--+-<span class="italic">built-in-type</span>------+---------------------------------------|
'-<span class="italic">distinct-type-name</span>-'
</pre>
<a name="skipsyn-409" id="skipsyn-409"></a>
<a name="wq1864"></a>
<div class="notelisttitle" id="wq1864">Notes:</div>
<ol type="1">
<li>The DEFAULT and NOT NULL clauses can be specified in either order.</li>
<li><var class="pv">specific-condition-value</var> and <var class="pv">general-condition-value</var> cannot be specified in the same handler declaration.</li>
</ol>
<a name="wq1866"></a>
<div class="fignone" id="wq1866">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn411.htm"
border="0" /></span><a href="#skipsyn-410"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>built-in-type:
|--+-+---SMALLINT---+-----------------------------------------------------------------+--|
| +-+-INTEGER-+--+ |
| | '-INT-----' | |
| '---BIGINT-----' |
| .-(--5,0--)--------------------. |
+-+-+-DECIMAL-+-+--+------------------------------+--------------------------------+
| | '-DEC-----' | | .-,0--------. | |
| '-NUMERIC-----' '-(--<span class="italic">integer</span>--+-----------+--)-' |
| '-<span class="italic">, integer</span>-' |
| .-(--53--)------. |
+-+-FLOAT--+---------------+-+-----------------------------------------------------+
| | '-(--<span class="italic">integer</span>--)-' | |
| +-REAL---------------------+ |
| | .-PRECISION-. | |
| '-DOUBLE--+-----------+----' |
| .-(--1--)-------. |
+-+-+-+-CHARACTER-+--+---------------+----------+--+----------------+------------+-+
| | | '-CHAR------' '-(--<span class="italic">integer</span>--)-' | +-FOR BIT DATA---+ | |
| | '-+-+-CHARACTER-+--VARYING-+--(--<span class="italic">integer</span>--)-' +-FOR SBCS DATA--+ | |
| | | '-CHAR------' | +-FOR MIXED DATA-+ | |
| | '-VARCHAR----------------' '-CCSID--<span class="italic">integer</span>-' | |
| | .-(--1M--)-------------. | |
| '---+-CLOB-------------------+----+----------------------+--+----------------+-' |
| +-CHAR LARGE OBJECT------+ '-(--<span class="italic">integer</span>--+---+--)-' +-FOR SBCS DATA--+ |
| '-CHARACTER LARGE OBJECT-' +-K-+ +-FOR MIXED DATA-+ |
| +-M-+ '-CCSID--<span class="italic">integer</span>-' |
| '-G-' |
| .-(--1--)-------. |
+-+---GRAPHIC----+---------------+-------+--+----------------+---------------------+
| | '-(--<span class="italic">integer</span>--)-' | '-CCSID--<span class="italic">integer</span>-' |
| +-+-GRAPHIC VARYING-+--(--<span class="italic">integer</span>--)---+ |
| | '-VARGRAPHIC------' | |
| | .-(--1M--)-------------. | |
| '---DBCLOB----+----------------------+-' |
| '-(--<span class="italic">integer</span>--+---+--)-' |
| +-K-+ |
| +-M-+ |
| '-G-' |
| .-(--1--)-------. |
+-+-+-BINARY--+---------------+---------+-----------------+------------------------+
| | | '-(--<span class="italic">integer</span>--)-' | | |
| | '-+-BINARY VARYING-+--(--<span class="italic">integer</span>--)-' | |
| | '-VARBINARY------' | |
| | .-(--1M--)-------------. | |
| '---+-BLOB----------------+----+----------------------+-' |
| '-BINARY LARGE OBJECT-' '-(--<span class="italic">integer</span>--+---+--)-' |
| +-K-+ |
| +-M-+ |
| '-G-' |
+-+-DATE------+--------------------------------------------------------------------+
| +-TIME------+ |
| '-TIMESTAMP-' |
| .-(--200--)-----. |
+---DATALINK--+---------------+--+----------------+--------------------------------+
| '-(--<span class="italic">integer</span>--)-' '-CCSID--<span class="italic">integer</span>-' |
'---ROWID--------------------------------------------------------------------------'
</pre>
<a name="skipsyn-410" id="skipsyn-410"></a></div>
<a name="synccompound"></a>
<h3 id="synccompound"><a href="rbafzmst02.htm#ToC_1427">Description</a></h3>
<dl class="parml">
<dt class="bold"><span class="italic">label</span></dt>
<dd>Specifies the label for the <span class="italic">compound-statement</span> statement. If the ending label is specified, it must be the same as
the beginning label. The label name cannot be the same as another label within
the same scope. For more information, see <a href="rbafzmstsqlprocstmt.htm#psscope">Labels</a>.
</dd>
<dt class="bold">ATOMIC</dt>
<dd>ATOMIC indicates that an unhandled exception within the <span class="italic">compound-statement</span> causes the <span class="italic">compound-statement</span> to be rolled back. If ATOMIC is specified, COMMIT or ROLLBACK statements
cannot be specified in the compound statement (ROLLBACK TO SAVEPOINT may be
specified).
</dd>
<dt class="bold">NOT ATOMIC</dt>
<dd>NOT ATOMIC indicates that an unhandled exception within the <span class="italic">compound-statement</span> does not causes the <span class="italic">compound-statement</span> to be rolled back. If NOT ATOMIC is specified in the outermost compound
statement of an SQL trigger, it is treated as ATOMIC.
</dd>
<dt class="bold"><span class="italic">SQL-variable-declaration</span></dt>
<dd>Declares a variable that is local to the compound statement.
<dl class="parml">
<dt class="bold"><span class="italic">SQL-variable-name</span></dt>
<dd>Defines the name of a local variable. The database manager converts
all undelimited SQL variable names to uppercase. The <span class="italic">SQL-variable-name</span> must be unique within the <span class="italic">compound-statement</span> (excluding
any declarations in <span class="italic">compound-statements</span> nested within
the <span class="italic">compound-statement</span>). SQL variable names should
not be the same as column names or SQL parameter names. See <a href="rbafzmstrefsqlv.htm#refsqlv">References to SQL parameters and SQL variables</a> for
how SQL variable names are resolved when there are columns with the same name
involved in a statement. Variable names should not begin with 'SQL'.
<p>An <span class="italic">SQL-variable-name</span> can only be referenced within the <span class="italic">compound-statement</span> in which it is declared (including
any <span class="italic">compound-statements</span> nested within the <span class="italic">compound-statement</span>).</p>
</dd>
<dt class="bold"><span class="italic">data-type</span></dt>
<dd>Specifies the data type of the variable. See <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a> for
a description of data type.
<p>If the <span class="italic">data-type</span> 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.</p>
</dd>
<dt class="bold">DEFAULT <span class="italic">constant</span> <span class="base">or</span> NULL</dt>
<dd>Defines the default for the SQL variable. The specified constant
must represent a value that could be assigned to the variable in accordance
with the rules of assignment as described in <a href="rbafzmstch2bas.htm#ch2bas">Assignments and comparisons</a>. The variable
will be initialized when the SQL procedure, SQL function, or SQL trigger is
invoked. If a default value is not specified, the SQL variable is initialized
to NULL.
</dd>
<dt class="bold">NOT NULL</dt>
<dd>Prevents the SQL variable from containing the NULL value. Omission of
NOT NULL implies that the column can be null.
</dd>
</dl>
</dd>
<dt class="bold"><span class="italic">condition-declaration</span></dt>
<dd>Declares a condition name and corresponding SQLSTATE value.
<dl class="parml">
<dt class="bold"><span class="italic">condition-name</span></dt>
<dd>Specifies the name of the condition. The condition name must be unique
within the <span class="italic">compound-statement</span> (excluding any declarations
in <span class="italic">compound-statements</span> nested within the <span class="italic">compound-statement</span>).
<p>A <span class="italic">condition-name</span> can only
be referenced within the <span class="italic">compound-statement</span> in which
it is declared (including any <span class="italic">compound-statements</span> nested
within the <span class="italic">compound-statement</span>).</p>
</dd>
<dt class="bold">FOR SQLSTATE <span class="italic">string-constant</span></dt>
<dd>Specifies the SQLSTATE associated with this condition. The string constant
must be specified as 5 characters, and cannot be '00000'.
</dd>
</dl>
</dd>
<dt class="bold"><span class="italic">return-codes-declaration</span></dt>
<dd>Declares special variables called SQLSTATE and SQLCODE that are set
automatically to the SQL return codes returned after executing an SQL statement.
Both the SQLSTATE and SQLCODE variables can only be declared in the outermost <span class="italic">compound-statement</span> of an SQL procedure, SQL function,
or SQL trigger.
<p>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.</p>
<p>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.</p>
</dd>
<dt class="bold"><span class="italic">DECLARE CURSOR-statement</span></dt>
<dd>Declares a cursor in the routine body. The cursor name must be unique
within the <span class="italic">compound-statement</span> (excluding any declarations
in <span class="italic">compound-statements</span> nested within the <span class="italic">compound-statement</span>).
<p>A <span class="italic">cursor-name</span> can only
be referenced within the <span class="italic">compound-statement</span> in which
it is declared (including any <span class="italic">compound-statements</span> nested
within the <span class="italic">compound-statement</span>).</p>
<p>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: </p>
<ul>
<li>specify WITH RETURN when declaring the cursor</li>
<li>create the procedure using the DYNAMIC RESULT SETS clause with a non-zero
value</li>
<li>do not specify a CLOSE statement in the <var class="pv">compound-statement</var>.</li></ul><p class="indatacontent"> Any open cursor that does not meet these criteria is closed at the end
of the <var class="pv">compound-statement</var>.</p>
<p>For more information on declaring
a cursor, refer to <a href="rbafzmsth2clcu.htm#h2dclcu">DECLARE CURSOR</a>.</p>
</dd>
<dt class="bold"><span class="italic">handler-declaration</span></dt>
<dd>Specifies a <span class="italic">handler</span>, an <span class="italic">SQL-procedure-statement</span> to execute when an exception or completion condition
occurs in the <span class="italic">compound-statement</span>.
<p>A handler is active
for the set of <var class="pv">SQL-procedure-statements</var> that follow the <var class="pv">handler-declarations</var> within the <var class="pv">compound-statement</var> in which it is declared.</p>
<p>A handler for a condition may exist at several levels of nested compound statements.
For example, assume that compound statement <span class="italic">n1</span> contains
another compound statement <span class="italic">n2</span> which contains another
compound statement <span class="italic">n3</span>. When an exception condition
occurs within <span class="italic">n3</span>, any active handlers within <span class="italic">n3</span> are first allowed to handle the condition. If no appropriate handler
exists in <span class="italic">n3</span>, then the condition is resignalled to <span class="italic">n2</span> and the active handlers within <span class="italic">n2</span> may handle the condition. If no appropriate handler exists in <span class="italic">n2</span>, then the condition is resignalled to <span class="italic">n1</span> and the active handlers within <span class="italic">n1</span> may handle
the condition. If no appropriate handler exists in <span class="italic">n1</span>,
the condition is considered unhandled.</p>
<p>There are three types of condition
handlers:</p>
<dl class="parml">
<dt class="bold">CONTINUE</dt>
<dd>After the handler is invoked successfully, control is returned to the
SQL statement following the one that raised the exception. If the error occurs
while executing a comparison as in an IF, CASE, FOR, WHILE, or REPEAT, control
returns to the statement following the corresponding END IF, END CASE, END
FOR, END WHILE, or END REPEAT.
</dd>
<dt class="bold">EXIT</dt>
<dd>Once the handler is invoked successfully, control is returned to the
end of the compound statement that declared the handler.
</dd>
<dt class="bold">UNDO</dt>
<dd>ROLLBACK the changes made by the <span class="italic">compound-statement</span> and invoke the handler. Once the handler is invoked successfully, control
is returned to the end of the <span class="italic">compound-statement</span>.
If UNDO is specified, then ATOMIC must be specified.
<p>UNDO cannot be specified
in the outermost <span class="italic">compound-statement</span> of an SQL function
or SQL trigger.</p>
</dd>
</dl>
<p>The conditions under which the handler is activated are:</p>
<dl class="parml">
<dt class="bold">SQLSTATE <span class="italic">string</span></dt>
<dd>Specifies that the handler is invoked when the specific SQLSTATE condition
occurs. The first two characters of the SQLSTATE value cannot be '00'.
</dd>
<dt class="bold"><span class="italic">condition-name</span></dt>
<dd>Specifies that the handler is invoked when the condition occurs. The
condition name must be previously defined in a <span class="italic">condition-declaration</span>.
</dd>
<dt class="bold">SQLEXCEPTION</dt>
<dd>Specifies that the handler is invoked when an exception condition occurs.
An exception condition is represented by an SQLSTATE value where the first
two characters are not '00', '01', or '02'.
</dd>
<dt class="bold">SQLWARNING</dt>
<dd>Specifies that the handler is invoked when a warning condition occurs.
A warning condition is represented by an SQLSTATE value where the first two
characters are '01'.
</dd>
<dt class="bold">NOT FOUND</dt>
<dd>Specifies that the handler is invoked when a NOT FOUND condition occurs.
A NOT FOUND condition is represented by an SQLSTATE value where the first
two characters are '02'.
</dd>
</dl><p class="indatacontent">The same condition cannot be specified more than once in the <span class="italic">handler-declaration</span>.</p>
<p>If the <var class="pv">SQL-procedure-statement</var> specified in the handler is either a SIGNAL or RESIGNAL statement with
an exception SQLSTATE, the <var class="pv">compound-statement</var> will exit with the
specified exception even if this handler or another handler in the same <var class="pv">compound-statement</var> specifies CONTINUE, since these handlers are not in
the scope of this exception. If the <var class="pv">compound-statement</var> is nested
in another <var class="pv">compound-statement</var>, handlers in the higher level <var class="pv">compound-statement</var> may handle the exception because those handlers are
within the scope of the exception.</p>
</dd>
</dl>
<a name="wq1867"></a>
<h3 id="wq1867"><a href="rbafzmst02.htm#ToC_1428">Notes</a></h3>
<p><span class="bold">Nesting compound statements</span>: 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.</p>
<p><span class="bold">Rules for <span class="italic">handler-declaration</span></span>:</p>
<ul>
<li>Handler declarations within the same compound statement cannot contain
duplicate conditions.</li>
<li>A handler declaration cannot contain the same condition value or SQLSTATE
value more than once, and cannot contain a SQLSTATE value and a condition
name that represents the same SQLSTATE value. For a list of SQLSTATE values
as well as more information, see the <a href="../sqlp/rbafykickoff.htm">SQL Programming</a> book.</li>
<li>A handler is activated when it is the most appropriate handler for an
exception or completion condition. The most appropriate handler is a handler
(for the exception or completion condition) that is defined in the <span class="italic">compound-statement</span> which most closely matches the SQLSTATE of the exception
or completion condition. For example, if a handler exists for SQLSTATE 22001
as well as a handler for SQLEXCEPTION, the handler for SQLSTATE 22001 would
be the most appropriate handler when an SQLSTATE 22001 is signalled. If an
exception occurs for which there is no handler, execution of the <span class="italic">compound-statement</span> is terminated. If a warning or not found condition
occurs for which there is no handler, processing continues with the next statement.</li></ul>
<p><span class="bold">Null values in SQL parameters and SQL variables</span>: 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.</p>
<a name="wq1868"></a>
<h3 id="wq1868"><a href="rbafzmst02.htm#ToC_1429">Examples</a></h3>
<p>Create a procedure body with a compound statement that performs the following
actions. </p>
<ol type="1">
<li>Declares SQL variables.</li>
<li>Declares a cursor to return the salary of employees in a department determined
by an IN parameter.</li>
<li>Declares an EXIT handler for the condition NOT FOUND (end of file) which
assigns the value 6666 to the OUT parameter <tt class="xph">medianSalary</tt>.</li>
<li>Select the number of employees in the given department into the SQL variable <tt class="xph">v_numRecords.</tt></li>
<li>Fetch rows from the cursor in a WHILE loop until 50% + 1 of the
employees have been retrieved.</li>
<li>Return the median salary.</li></ol>
<pre class="xmp"> <span class="bold">CREATE PROCEDURE</span> DEPT_MEDIAN
<span class="bold">(IN</span> deptNumber <span class="bold">SMALLINT</span>,
<span class="bold"> OUT</span> medianSalary <span class="bold">DOUBLE)</span>
<span class="bold">LANGUAGE SQL</span>
<span class="bold">BEGIN</span>
<span class="bold">DECLARE</span> v_numRecords <span class="bold">INTEGER DEFAULT</span> 1;
<span class="bold">DECLARE</span> v_counter <span class="bold">INTEGER DEFAULT</span> 0;
<span class="bold">DECLARE</span> c1 <span class="bold">CURSOR FOR</span>
<span class="bold">SELECT</span> salary <span class="bold">FROM</span> staff
<span class="bold">WHERE</span> DEPT = deptNumber
<span class="bold">ORDER BY </span>salary;
<span class="bold">DECLARE EXIT HANDLER FOR NOT FOUND</span>
<span class="bold">SET</span> medianSalary = 6666;
/* initialize OUT parameter */
<span class="bold">SET</span> medianSalary = 0;
<span class="bold">SELECT COUNT(*) INTO</span> v_numRecords <span class="bold">FROM</span> staff
<span class="bold">WHERE</span> DEPT = deptNumber;
<span class="bold">OPEN</span> c1;
<span class="bold">WHILE</span> v_counter &lt; (v_numRecords / 2 + 1) <span class="bold">DO</span>
<span class="bold">FETCH</span> c1 <span class="bold">INTO</span> medianSalary;
<span class="bold">SET</span> v_counter = v_counter + 1;
<span class="bold">END WHILE</span>;
<span class="bold">CLOSE</span> c1;
<span class="bold">END</span></pre>
<p></p>
<hr /><br />
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmstcasestmt.htm">Previous Page</a> | <a href="rbafzmstforstmt.htm">Next Page</a> | <a href="rbafzmst02.htm#wq1">Contents</a> |
<a href="rbafzmstindex.htm#index">Index</a> ]
<a id="Bot_Of_Page" name="Bot_Of_Page"></a>
</body>
</html>