640 lines
40 KiB
HTML
640 lines
40 KiB
HTML
<?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="CREATE PROCEDURE (SQL) statement,
|
|
CREATE PROCEDURE (SQL), SQL statement, creating, procedure, CCSID clause,
|
|
data type for CREATE PROCEDURE (SQL), CHAR, DOUBLE PRECISION, DECIMAL, FLOAT,
|
|
BIGINT, INTEGER, NUMERIC, REAL, SMALLINT, VARCHAR, VARGRAPHIC, GRAPHIC,
|
|
FOR BIT DATA clause, FOR MIXED DATA clause, FOR SBCS DATA clause, BINARY,
|
|
VARBINARY, BLOB, CLOB, DBCLOB, DATALINK, ROWID, distinct-type,
|
|
in CREATE PROCEDURE (SQL), procedure-name, IN clause, OUT clause, INOUT clause,
|
|
parameter-name, data-type, LANGUAGE clause, RESULT SETS clause, SPECIFIC clause,
|
|
DETERMINISTIC clause, NOT DETERMINISTIC clause, CONTAINS SQL clause,
|
|
READS SQL DATA clause, MODIFIES SQL DATA clause, CALLED ON NULL INPUT clause,
|
|
DEBUG MODE clause, FENCED clause, NOT FENCED clause, SAVEPOINT LEVEL clause,
|
|
COMMIT ON RETURN clause, SQL statements" />
|
|
<title>CREATE PROCEDURE (SQL)</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="crtpsf"></a>
|
|
<h2 id="crtpsf"><a href="rbafzmst02.htm#ToC_904">CREATE PROCEDURE (SQL)</a></h2><a id="idx1976" name="idx1976"></a><a id="idx1977" name="idx1977"></a><a id="idx1978" name="idx1978"></a>
|
|
<p>The CREATE PROCEDURE (SQL) statement creates an SQL procedure at the current
|
|
server.</p>
|
|
<a name="wq1273"></a>
|
|
<h3 id="wq1273"><a href="rbafzmst02.htm#ToC_905">Invocation</a></h3>
|
|
<p>This statement can be embedded in an application program or issued interactively.
|
|
It is an executable statement that can be dynamically prepared.</p>
|
|
<a name="wq1274"></a>
|
|
<h3 id="wq1274"><a href="rbafzmst02.htm#ToC_906">Authorization</a></h3>
|
|
<p>The privileges held by the authorization ID of the statement must include
|
|
at least one of the following:</p>
|
|
<ul>
|
|
<li>The privilege to create in the schema. For more information, see <a href="rbafzmstauthown.htm#createin">Privileges necessary to create in a schema</a>.</li>
|
|
<li>Administrative authority</li></ul>
|
|
<p>The privileges held by the authorization ID of the statement must include
|
|
at least one of the following: </p>
|
|
<ul>
|
|
<li>For the SYSPROCS catalog view and SYSPARMS catalog table:
|
|
<ul>
|
|
<li>The INSERT privilege on the table, and</li>
|
|
<li>The system authority *EXECUTE on library QSYS2</li></ul></li>
|
|
<li>Administrative authority</li></ul>
|
|
<p>The privileges held by the authorization ID of the statement must include
|
|
at least one of the following: </p>
|
|
<ul>
|
|
<li>The following system authorities:
|
|
<ul>
|
|
<li>*USE on the Create Program (CRTPGM) command, and</li></ul></li>
|
|
<li>Administrative authority</li></ul>
|
|
<p>If SQL names are specified and a user profile exists that has the same
|
|
name as the library into which the procedure is created, and that name is
|
|
different from the authorization ID of the statement, then the privileges
|
|
held by the authorization ID of the statement must include at least one of
|
|
the following:</p>
|
|
<ul>
|
|
<li>The system authority *ADD to the user profile with that name</li>
|
|
<li>Administrative authority</li></ul>
|
|
<p>If a distinct type is referenced, the privileges held by the authorization ID of
|
|
the statement must include at least one of the following: </p>
|
|
<ul>
|
|
<li>For each distinct type identified in the statement:
|
|
<ul>
|
|
<li>The USAGE privilege on the distinct type, and</li>
|
|
<li>The system authority *EXECUTE on the library containing the distinct type</li></ul></li>
|
|
<li>Administrative authority</li></ul>
|
|
<p>For information on the system authorities corresponding to SQL privileges,
|
|
see <a href="rbafzmstgntprc.htm#eqtabler">Corresponding System Authorities When Checking Privileges to a Function or Procedure</a> and <a href="rbafzmstgntudtp.htm#eqtabled">Corresponding System Authorities When Checking Privileges to a Distinct Type</a>.</p>
|
|
<a name="wq1275"></a>
|
|
<h3 id="wq1275"><a href="rbafzmst02.htm#ToC_907">Syntax</a></h3>
|
|
<a href="rbafzmstcrtpsf.htm#synscrtprocs"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
|
<a name="wq1276"></a>
|
|
<div class="fignone" id="wq1276">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn295.htm"
|
|
border="0" /></span><a href="#skipsyn-294"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a>>>-CREATE PROCEDURE--<span class="italic">procedure-name</span>----------------------------->
|
|
|
|
>--+-----------------------------------------+------------------>
|
|
'-(--+-------------------------------+--)-'
|
|
| .-,-------------------------. |
|
|
| V | |
|
|
'-----<span class="italic">parameter-declaration</span>---+-'
|
|
|
|
>--LANGUAGE SQL--<span class="italic">option-list</span>--+----------------------+--<span class="italic">SQL-routine-body</span>-><
|
|
'-<span class="italic">SET OPTION-statement</span>-'
|
|
|
|
</pre>
|
|
<a name="skipsyn-294" id="skipsyn-294"></a></div>
|
|
<a name="wq1277"></a>
|
|
<div class="fignone" id="wq1277">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn296.htm"
|
|
border="0" /></span><a href="#skipsyn-295"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a>parameter-declaration:
|
|
|
|
.-IN----.
|
|
|--+-------+--<span class="italic">parameter-name</span>--<span class="italic">data-type</span>-------------------------|
|
|
+-OUT---+
|
|
'-INOUT-'
|
|
|
|
data-type:
|
|
|
|
|--+-<span class="italic">built-in-type</span>------+---------------------------------------|
|
|
'-<span class="italic">distinct-type-name</span>-'
|
|
|
|
</pre>
|
|
<a name="skipsyn-295" id="skipsyn-295"></a></div>
|
|
<a name="wq1278"></a>
|
|
<div class="fignone" id="wq1278">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn297.htm"
|
|
border="0" /></span><a href="#skipsyn-296"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a>option-list:
|
|
|
|
.-NOT DETERMINISTIC-. (1) .-MODIFIES SQL DATA-.
|
|
|--+-------------------+-------+-------------------+------------>
|
|
'-DETERMINISTIC-----' +-READS SQL DATA----+
|
|
'-CONTAINS SQL------'
|
|
|
|
.-CALLED ON NULL INPUT-. .-DYNAMIC RESULT SETS--<span class="italic">0</span>-------.
|
|
>--+----------------------+--+------------------------------+--->
|
|
'-DYNAMIC RESULT SETS--<span class="italic">integer</span>-'
|
|
|
|
>--+-------------------------+--+---------------------+--------->
|
|
'-SPECIFIC--<span class="italic">specific-name</span>-' +-<span>DISALLOW DEBUG MODE</span>-+
|
|
+-<span>ALLOW DEBUG MODE</span>----+
|
|
'-<span>DISABLE DEBUG MODE</span>--'
|
|
|
|
.-FENCED-----. .-OLD SAVEPOINT LEVEL-.
|
|
>--+------------+--+---------------------+---------------------->
|
|
'-NOT FENCED-' '-NEW SAVEPOINT LEVEL-'
|
|
|
|
.-COMMIT ON RETURN NO--.
|
|
>--+----------------------+-------------------------------------|
|
|
'-COMMIT ON RETURN YES-'
|
|
|
|
</pre>
|
|
<a name="skipsyn-296" id="skipsyn-296"></a>
|
|
<a name="wq1279"></a>
|
|
<div class="notelisttitle" id="wq1279">Notes:</div>
|
|
<ol type="1">
|
|
<li>The optional clauses can be specified in a different order.</li>
|
|
</ol></div>
|
|
<a name="wq1281"></a>
|
|
<div class="fignone" id="wq1281">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn298.htm"
|
|
border="0" /></span><a href="#skipsyn-297"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a>SQL-routine-body:
|
|
|
|
|--+-<span class="italic">SQL-control-statement</span>-----------------------+--------------|
|
|
+-<span><span class="italic">ALLOCATE DESCRIPTOR-statement</span></span>---------------+
|
|
+-<span class="italic">ALTER PROCEDURE (External)-statement</span>--------+
|
|
+-<span class="italic">ALTER SEQUENCE-statement</span>--------------------+
|
|
+-<span class="italic">ALTER TABLE-statement</span>-----------------------+
|
|
+-<span class="italic">COMMENT-statement</span>---------------------------+
|
|
+-<span class="italic">COMMIT-statement</span>----------------------------+
|
|
+-<span class="italic">CONNECT-statement</span>---------------------------+
|
|
+-<span class="italic">CREATE ALIAS-statement</span>----------------------+
|
|
+-<span class="italic">CREATE DISTINCT TYPE-statement</span>--------------+
|
|
+-<span class="italic">CREATE FUNCTION (External Scalar)-statement</span>-+
|
|
+-<span class="italic">CREATE FUNCTION (External Table)-statement</span>--+
|
|
+-<span class="italic">CREATE FUNCTION (Sourced)-statement</span>---------+
|
|
+-<span class="italic">CREATE INDEX-statement</span>----------------------+
|
|
+-<span class="italic">CREATE PROCEDURE (External)-statement</span>-------+
|
|
+-<span class="italic">CREATE SCHEMA-statement</span>---------------------+
|
|
+-<span class="italic">CREATE SEQUENCE-statement</span>-------------------+
|
|
+-<span class="italic">CREATE TABLE-statement</span>----------------------+
|
|
+-<span class="italic">CREATE VIEW-statement</span>-----------------------+
|
|
+-<span><span class="italic">DEALLOCATE DESCRIPTOR-statement</span></span>-------------+
|
|
+-<span class="italic">DECLARE GLOBAL TEMPORARY TABLE-statement</span>----+
|
|
+-<span class="italic">DELETE-statement</span>----------------------------+
|
|
+-<span><span class="italic">DESCRIBE-statement</span></span>--------------------------+
|
|
+-<span><span class="italic">DESCRIBE INPUT-statement</span></span>--------------------+
|
|
+-<span><span class="italic">DESCRIBE TABLE-statement</span></span>--------------------+
|
|
+-<span class="italic">DISCONNECT-statement</span>------------------------+
|
|
+-<span class="italic">DROP-statement</span>------------------------------+
|
|
+-<span class="italic">EXECUTE IMMEDIATE-statement</span>-----------------+
|
|
+-<span><span class="italic">GET DESCRIPTOR-statement</span></span>--------------------+
|
|
+-<span class="italic">GRANT-statement</span>-----------------------------+
|
|
+-<span class="italic">INSERT-statement</span>----------------------------+
|
|
+-<span class="italic">LABEL-statement</span>-----------------------------+
|
|
+-<span class="italic">LOCK TABLE-statement</span>------------------------+
|
|
+-<span class="italic">REFRESH TABLE-statement</span>---------------------+
|
|
+-<span class="italic">RELEASE-statement</span>---------------------------+
|
|
+-<span class="italic">RELEASE SAVEPOINT-statement</span>-----------------+
|
|
+-<span class="italic">RENAME-statement</span>----------------------------+
|
|
+-<span class="italic">REVOKE-statement</span>----------------------------+
|
|
+-<span class="italic">ROLLBACK-statement</span>--------------------------+
|
|
+-<span class="italic">SAVEPOINT-statement</span>-------------------------+
|
|
+-<span class="italic">SELECT INTO-statement</span>-----------------------+
|
|
+-<span class="italic">SET CONNECTION-statement</span>--------------------+
|
|
+-<span><span class="italic">SET CURRENT DEBUG MODE-statement</span></span>------------+
|
|
+-<span><span class="italic">SET CURRENT DEGREE-statement</span></span>----------------+
|
|
+-<span><span class="italic">SET DESCRIPTOR-statement</span></span>--------------------+
|
|
+-<span class="italic">SET ENCRYPTION PASSWORD-statement</span>-----------+
|
|
+-<span class="italic">SET PATH-statement</span>--------------------------+
|
|
+-<span class="italic">SET RESULT SETS-statement</span>-------------------+
|
|
+-<span class="italic">SET SCHEMA-statement</span>------------------------+
|
|
+-<span class="italic">SET TRANSACTION-statement</span>-------------------+
|
|
+-<span class="italic">UPDATE-statement</span>----------------------------+
|
|
'-<span class="italic">VALUES INTO-statement</span>-----------------------'
|
|
|
|
</pre>
|
|
<a name="skipsyn-297" id="skipsyn-297"></a></div>
|
|
<a name="wq1282"></a>
|
|
<div class="fignone" id="wq1282">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn299.htm"
|
|
border="0" /></span><a href="#skipsyn-298"><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----------------' '-<span class="italic">ccsid-clause</span>---' | |
|
|
| | .-(--1M--)-------------. | |
|
|
| '-----+-+-<span>CHARACTER</span>-+--<span>LARGE OBJECT</span>-+------+----------------------+--+----------------+-' |
|
|
| | '-<span>CHAR</span>------' | '-(--<span class="italic">integer</span>--+---+--)-' +-FOR SBCS DATA--+ |
|
|
| '-<span>CLOB</span>------------------------' +-K-+ +-FOR MIXED DATA-+ |
|
|
| +-M-+ '-<span class="italic">ccsid-clause</span>---' |
|
|
| '-G-' |
|
|
| .-(--1--)-------. |
|
|
+-+---GRAPHIC----+---------------+-------+--+--------------+--------------------------------+
|
|
| | '-(--<span class="italic">integer</span>--)-' | '-<span class="italic">ccsid-clause</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-------------------+----------------------------------------------------------------+
|
|
| | .-(--0--)-. | |
|
|
| +-TIME--+---------+------+ |
|
|
| | .-(--6--)-. | |
|
|
| '-TIMESTAMP--+---------+-' |
|
|
| .-(--200--)-----. |
|
|
+---DATALINK--+---------------+--+--------------+-------------------------------------------+
|
|
| '-(--<span class="italic">integer</span>--)-' '-<span class="italic">ccsid-clause</span>-' |
|
|
'---ROWID-----------------------------------------------------------------------------------'
|
|
|
|
ccsid-clause:
|
|
|
|
.-NOT NORMALIZED-.
|
|
|--CCSID--<span class="italic">integer</span>--+----------------+---------------------------|
|
|
'-NORMALIZED-----'
|
|
|
|
</pre>
|
|
<a name="skipsyn-298" id="skipsyn-298"></a></div>
|
|
<p><a id="idx1979" name="idx1979"></a><a id="idx1980" name="idx1980"></a><a id="idx1981" name="idx1981"></a><a id="idx1982" name="idx1982"></a><a id="idx1983" name="idx1983"></a><a id="idx1984" name="idx1984"></a><a id="idx1985" name="idx1985"></a><a id="idx1986" name="idx1986"></a><a id="idx1987" name="idx1987"></a><a id="idx1988" name="idx1988"></a><a id="idx1989" name="idx1989"></a><a id="idx1990" name="idx1990"></a><a id="idx1991" name="idx1991"></a><a id="idx1992" name="idx1992"></a><a id="idx1993" name="idx1993"></a><a id="idx1994" name="idx1994"></a><a id="idx1995" name="idx1995"></a><a id="idx1996" name="idx1996"></a><a id="idx1997" name="idx1997"></a><a id="idx1998" name="idx1998"></a><a id="idx1999" name="idx1999"></a><a id="idx2000" name="idx2000"></a><a id="idx2001" name="idx2001"></a><a id="idx2002" name="idx2002"></a></p>
|
|
<a name="synscrtprocs"></a>
|
|
<h3 id="synscrtprocs"><a href="rbafzmst02.htm#ToC_908">Description</a></h3>
|
|
<p></p>
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">procedure-name</var> </dt><a id="idx2003" name="idx2003"></a>
|
|
<dd>Names the procedure. The combination of name, schema name, the number
|
|
of parameters must not identify a procedure that exists at the current server.
|
|
<p>For SQL naming, the procedure will be created in the schema specified by the
|
|
implicit or explicit qualifier.</p>
|
|
<p>For system naming, the procedure will
|
|
be created in the schema specified by the qualifier. If no qualifier is specified:</p>
|
|
<ul>
|
|
<li>If the value of the CURRENT SCHEMA special register is *LIBL, the procedure
|
|
will be created in the current library (*CURLIB).</li>
|
|
<li>Otherwise, the procedure will be created in the current schema.</li></ul>
|
|
</dd>
|
|
<dt class="bold">(<var class="pv">parameter-declaration,...)</var></dt>
|
|
<dd>Specifies the number of parameters of the procedure and the data type
|
|
of each parameter. A parameter for a procedure can be used only for input,
|
|
only for output, or for both input and output. Although not required, you
|
|
can give each parameter a name.
|
|
<p>The maximum number of parameters
|
|
allowed in an SQL procedure is 1024.</p>
|
|
<dl class="parml">
|
|
<dt class="bold">IN</dt><a id="idx2004" name="idx2004"></a>
|
|
<dd>Identifies the parameter as an input parameter to the procedure. Any
|
|
changes made to the parameter within the procedure are not available to the
|
|
calling SQL application when control is returned.
|
|
</dd>
|
|
<dt class="bold">OUT </dt><a id="idx2005" name="idx2005"></a>
|
|
<dd>Identifies the parameter as an output parameter that is returned by
|
|
the procedure. If the parameter is not set within the procedure, the null
|
|
value is returned.
|
|
</dd>
|
|
<dt class="bold">INOUT </dt><a id="idx2006" name="idx2006"></a>
|
|
<dd>Identifies the parameter as both an input and output parameter for the
|
|
procedure.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">parameter-name</var> </dt><a id="idx2007" name="idx2007"></a>
|
|
<dd>Names the parameter. The name cannot be the same as any other <var class="pv">parameter-name</var> for the procedure.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">data-type</var> </dt><a id="idx2008" name="idx2008"></a>
|
|
<dd>Specifies the data type of the parameter. The data type can be a built-in
|
|
data type or a distinct data type.
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">built-in-type</var></dt>
|
|
<dd>Specifies a built-in data type. For a more complete description of each
|
|
built-in data type, see <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">distinct-type-name</var></dt>
|
|
<dd>Specifies a distinct type. The length, precision, or scale attributes
|
|
for the parameter are those of the source type of the distinct type (those
|
|
specified on CREATE DISTINCT TYPE). For more information on creating a distinct
|
|
type, see <a href="rbafzmstcrtudt.htm#crtudt">CREATE DISTINCT TYPE</a>.
|
|
<p>If the name of the distinct type is unqualified,
|
|
the database manager resolves the schema name by searching the schemas in
|
|
the SQL path.</p>
|
|
</dd>
|
|
</dl>
|
|
<p>If a CCSID is specified, the parameter will be converted to that
|
|
CCSID prior to passing it to the procedure. If a CCSID is not specified, the
|
|
CCSID is determined by the default CCSID at the current server at the time
|
|
the procedure is called.</p>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">LANGUAGE SQL<a id="idx2009" name="idx2009"></a></dt>
|
|
<dd>Specifies that this is an SQL procedure.
|
|
</dd>
|
|
<dt class="bold">DYNAMIC RESULT SETS <var class="pv">integer</var> </dt><a id="idx2010" name="idx2010"></a>
|
|
<dd>Specifies the maximum number of result sets that can be returned from
|
|
the procedure. <var class="pv">integer</var> must be greater than or equal to zero and
|
|
less than 32768. If zero is specified, no result sets are returned. If the
|
|
SET RESULT SETS statement is issued, the number of results returned is the
|
|
minimum of the number of result sets specified on this keyword and the SET
|
|
RESULT SETS statement. If the SET RESULT SETS statement specifies a number
|
|
larger than the maximum number of result sets, a warning is returned. Note
|
|
that any result sets from cursors that have a RETURN TO CLIENT attribute are
|
|
included in the number of result sets of the outermost procedure.
|
|
<p>The result
|
|
sets are scrollable if the cursor is used to return a result set and the cursor
|
|
is scrollable. If a cursor is used to return a result set, the result set
|
|
starts with the current position. Thus, if 5 FETCH NEXT operations have been
|
|
performed prior to returning from the procedure, the result set will start
|
|
with the 6th row of the result set.</p>
|
|
<p>Result sets are only
|
|
returned if the procedure is directly called or if the procedure is a RETURN
|
|
TO CLIENT procedure and is indirectly called from ODBC, JDBC, OLE DB, .NET,
|
|
the SQL Call Level Interface, or the iSeries Access Family Optimized SQL API. For more information
|
|
about result sets, see <a href="rbafzmsthsetrs.htm#hsetrs">SET RESULT SETS</a>.</p>
|
|
</dd>
|
|
<dt class="bold">SPECIFIC <var class="pv">specific-name</var> <a id="idx2011" name="idx2011"></a></dt>
|
|
<dd>Provides a unique name for the procedure. The name is implicitly or
|
|
explicitly qualified with a schema name. The name, including the schema name,
|
|
must not identify the specific name of another procedure or function that
|
|
exists at the current server. If unqualified, the implicit qualifier is the
|
|
same as the qualifier of the procedure name. If qualified, the qualifier must
|
|
be the same as the qualifier of the procedure name.
|
|
<p>If <var class="pv">specific-name</var> is not specified, it is the same as the procedure name. If a function
|
|
or procedure with that specific name already exists, a unique name is generated
|
|
similar to the rules used to generate unique table names.</p>
|
|
</dd>
|
|
<dt class="bold">DETERMINISTIC <span class="base">or</span> NOT DETERMINISTIC</dt><a id="idx2012" name="idx2012"></a><a id="idx2013" name="idx2013"></a>
|
|
<dd>Specifies whether the procedure returns the same results each time the
|
|
procedure is called with the same IN and INOUT arguments.
|
|
<dl class="parml">
|
|
<dt class="bold">NOT DETERMINISTIC</dt>
|
|
<dd>The procedure may not return the same result each time the procedure
|
|
is called with the same IN and INOUT arguments, even when the referenced data
|
|
in the database has not changed.
|
|
</dd>
|
|
<dt class="bold">DETERMINISTIC</dt>
|
|
<dd>The procedure always returns the same results each time the procedure
|
|
is called with the same IN and INOUT arguments, provided the referenced data
|
|
in the database has not changed.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">CONTAINS SQL, READS SQL DATA, <span class="base">or</span> MODIFIES
|
|
SQL DATA</dt>
|
|
<dd>Specifies which SQL statements may be executed in the procedure or any
|
|
routine called from this procedure. See <a href="rbafzmstdiftab.htm#diftab">Appendix B. Characteristics of SQL statements</a> for a detailed
|
|
list of the SQL statements that can be executed under each data access indication.
|
|
<dl class="parml">
|
|
<dt class="bold">CONTAINS SQL</dt><a id="idx2014" name="idx2014"></a>
|
|
<dd>Specifies that SQL statements that neither read nor modify SQL data
|
|
can be executed by the procedure.
|
|
</dd>
|
|
<dt class="bold">READS SQL DATA</dt><a id="idx2015" name="idx2015"></a>
|
|
<dd>Specifies that SQL statements that do not modify SQL data can be included
|
|
in the procedure.
|
|
</dd>
|
|
<dt class="bold">MODIFIES SQL DATA</dt><a id="idx2016" name="idx2016"></a>
|
|
<dd>Specifies that the procedure can execute any SQL statement except statements
|
|
that are not supported in procedures.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">CALLED ON NULL INPUT</dt><a id="idx2017" name="idx2017"></a>
|
|
<dd>Specifies that the procedure is to be invoked, if any, or
|
|
all, argument values are null, making the procedure responsible for testing
|
|
for null argument values. The procedure can return a null or nonnull value.
|
|
</dd>
|
|
<dt class="bold">DISALLOW DEBUG MODE, ALLOW DEBUG MODE, <span class="base">or</span> DISABLE DEBUG MODE</dt><a id="idx2018" name="idx2018"></a>
|
|
<dd>Indicates whether the procedure is created so it can be debugged by
|
|
the Unified Debugger. If DEBUG MODE is specified, a DBGVIEW option in the SET OPTION
|
|
statement must not be specified.
|
|
<dl class="parml">
|
|
<dt class="bold">DISALLOW DEBUG MODE</dt>
|
|
<dd>The procedure cannot be debugged by the Unified Debugger. When
|
|
the DEBUG MODE attribute of the procedure is DISALLOW, the procedure can be
|
|
subsequently altered to change the debug mode attribute.
|
|
</dd>
|
|
<dt class="bold">ALLOW DEBUG MODE</dt>
|
|
<dd>The procedure can be debugged by the Unified Debugger. When the DEBUG MODE
|
|
attribute of the procedure is ALLOW, the procedure can be subsequently altered
|
|
to change the debug mode attribute.
|
|
</dd>
|
|
<dt class="bold">DISABLE DEBUG MODE</dt>
|
|
<dd>The procedure cannot be debugged by the Unified Debugger. When the DEBUG MODE
|
|
attribute of the procedure is DISABLE, the procedure cannot be subsequently
|
|
altered to change the debug mode attribute.
|
|
</dd>
|
|
</dl>
|
|
<p>If DEBUG MODE is not specified, but a DBGVIEW option
|
|
in the SET OPTION statement is specified, the procedure cannot be debugged
|
|
by the Unified Debugger, but may be debugged by the system debug facilities.
|
|
If neither DEBUG MODE nor a DBGVIEW option is specified, the debug mode used
|
|
is from the CURRENT DEBUG MODE special register.</p>
|
|
</dd>
|
|
<dt class="bold">FENCED <span class="base">or</span> NOT FENCED</dt><a id="idx2019" name="idx2019"></a><a id="idx2020" name="idx2020"></a>
|
|
<dd>This parameter is allowed for compatibility with other products and
|
|
is not used by DB2 UDB for iSeries.
|
|
</dd>
|
|
<dt class="bold">OLD SAVEPOINT LEVEL <span class="base">or</span> NEW SAVEPOINT LEVEL</dt>
|
|
<dd>Specifies whether a new savepoint level is to be created on entry to
|
|
the procedure.
|
|
<dl class="parml"><a id="idx2021" name="idx2021"></a>
|
|
<dt class="bold">OLD SAVEPOINT LEVEL</dt>
|
|
<dd>A new savepoint level is not created. Any SAVEPOINT statements issued
|
|
within the procedure with OLD SAVEPOINT LEVEL implicitly or explicitly specified
|
|
on the SAVEPOINT statement are created at the same savepoint level as the
|
|
caller of the procedure. This is the default.
|
|
</dd>
|
|
<dt class="bold">NEW SAVEPOINT LEVEL</dt>
|
|
<dd>A new savepoint level is created on entry to the procedure. Any savepoints
|
|
set within the procedure are created at a savepoint level that is nested deeper
|
|
than the level at which this procedure was invoked. Therefore, the name of
|
|
any new savepoint set within the procedure will not conflict with any existing
|
|
savepoints set in higher savepoint levels (such as the savepoint level of
|
|
the calling program) with the same name.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">COMMIT ON RETURN</dt>
|
|
<dd>Specifies whether the database manager commits the transaction immediately on return
|
|
from the procedure.
|
|
<dl class="parml"><a id="idx2022" name="idx2022"></a>
|
|
<dt class="bold">NO</dt>
|
|
<dd>The database manager does not issue a commit when the procedure returns. NO is
|
|
the default.
|
|
</dd>
|
|
<dt class="bold">YES</dt>
|
|
<dd>The database manager issues a commit if the procedure returns successfully. If
|
|
the procedure returns with an error, a commit is not issued.
|
|
<p>The commit
|
|
operation includes the work that is performed by the calling application process
|
|
and the procedure.</p>
|
|
<p>If the procedure returns result sets, the cursors
|
|
that are associated with the result sets must have been defined as WITH HOLD
|
|
to be usable after the commit.</p>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold"><span class="italic">SET OPTION-statement</span></dt>
|
|
<dd>Specifies the options that will be used to create the procedure. For
|
|
example, to create a debuggable procedure, the following statement could be
|
|
included:
|
|
<pre class="xmp"><span class="bold">SET OPTION DBGVIEW = *SOURCE</span> </pre>For
|
|
more information, see <a href="rbafzmstsoption.htm#soption">SET OPTION</a>.
|
|
<p>The options CLOSQLCSR,
|
|
CNULRQD, COMPILEOPT, NAMING, and SQLCA are not allowed in the CREATE PROCEDURE
|
|
statement.</p>
|
|
</dd>
|
|
<dt class="bold"><span class="italic">SQL-routine-body</span></dt>
|
|
<dd>Specifies a single SQL statement, including a compound statement. See <a href="rbafzmstsqlcontstmts.htm#sqlcontstmts">SQL control statements</a> for more information about defining SQL procedures.
|
|
<p>CONNECT, SET CONNECTION, RELEASE, DISCONNECT, and SET TRANSACTION statements
|
|
are not allowed in a procedure that is running on a remote application server. COMMIT
|
|
and ROLLBACK statements are not allowed in an ATOMIC SQL procedure or in a
|
|
procedure that is running on a connection to a remote application server.</p>
|
|
</dd>
|
|
</dl>
|
|
<a name="wq1283"></a>
|
|
<h3 id="wq1283"><a href="rbafzmst02.htm#ToC_909">Notes</a></h3>
|
|
<p><span class="bold">General considerations for defining procedures:</span> See <a href="rbafzmstcreatep.htm#createp">CREATE PROCEDURE</a> for general information on defining procedures.</p>
|
|
<p><span class="bold">Procedure ownership:</span> If SQL names were
|
|
specified:</p>
|
|
<ul>
|
|
<li>If a user profile with the same name as the schema into which the procedure
|
|
is created exists, the <span class="italic">owner</span> of the procedure is that
|
|
user profile.</li>
|
|
<li>Otherwise, the <span class="italic">owner</span> of the procedure is the user
|
|
profile or group user profile of the job executing the statement.</li></ul>
|
|
<p>If system names were specified, the <span class="italic">owner</span> of the
|
|
procedure is the user profile or group user profile of the job executing the
|
|
statement.</p>
|
|
<p><span class="bold">Procedure authority:</span> If SQL names are used, procedures
|
|
are created with the system authority of *EXCLUDE on *PUBLIC. If system names
|
|
are used, procedures are created with the authority to *PUBLIC as determined
|
|
by the create authority (CRTAUT) parameter of the schema.</p>
|
|
<p>If the owner of the procedure is a member of a group profile (GRPPRF keyword)
|
|
and group authority is specified (GRPAUT keyword), that group profile will
|
|
also have authority to the procedure.</p>
|
|
<p><span class="bold">Error handling in procedures:</span> Consideration should
|
|
be given to possible exceptions that can occur for each SQL statement in the
|
|
body of a procedure. Any exception SQLSTATE that is not handled within the
|
|
procedure using a handler within a compound statement, results in the exception
|
|
SQLSTATE being returned to the caller of the procedure.</p>
|
|
<p><span class="bold">Creating the procedure:</span> When an SQL procedure is
|
|
created, SQL creates a temporary source file that will contain C source code
|
|
with embedded SQL statements. A program object is then created using the CRTPGM
|
|
command. The SQL options used to create the program are the options that are
|
|
in effect at the time the CREATE PROCEDURE statement is executed. The program
|
|
is created with ACTGRP(*CALLER).</p>
|
|
<p>When an SQL procedure is created, the procedure's attributes are stored
|
|
in the created program object. If the *PGM object is saved and then restored
|
|
to this or another system, the catalogs are automatically updated with those
|
|
attributes.</p>
|
|
<p>During restore of the procedure:</p>
|
|
<ul>
|
|
<li>If the specific name was specified when the procedure was originally created
|
|
and it is not unique, an error is issued.</li>
|
|
<li>If the specific name was not specified, a unique name is generated if
|
|
necessary.</li>
|
|
<li>If the same procedure name and number of parameters already exists,
|
|
<ul>
|
|
<li>If the name of the created program is the same as the one registered in
|
|
the catalog, the procedure information in the catalog will be replaced.</li>
|
|
<li>Otherwise, the procedure cannot be registered, and an error is issued.</li></ul></li></ul>
|
|
<p>The specific procedure name is used as the name of the member
|
|
in the source file and the name of the program object, if it is a valid system
|
|
name. If the procedure name is not a valid system name, a unique name is generated.
|
|
If a source file member with the same name already exists, the member is overlaid.
|
|
If a module or a program with the same name already exists, the objects are
|
|
not overlaid, and a unique name is generated. The unique names are generated
|
|
according to the rules for generating system table names.</p>
|
|
<p><span class="bold">Invoking the procedure:</span> If a DECLARE PROCEDURE statement
|
|
defines a procedure with the same name as a created procedure, and a static
|
|
CALL statement where the procedure name is not identified by a variable is
|
|
executed from the same source program, the attributes from the DECLARE PROCEDURE
|
|
statement will be used rather than the attributes from the CREATE PROCEDURE
|
|
statement.</p>
|
|
<p>The CREATE PROCEDURE statement applies to static and dynamic CALL statements
|
|
as well as to a CALL statement where the procedure name is identified by a
|
|
variable.</p>
|
|
<p>SQL procedures must be called using the SQL CALL statement. When called,
|
|
the SQL procedure runs in the activation group of the calling program.</p>
|
|
<p><span class="bold">Syntax alternatives:</span> The following keywords are synonyms
|
|
supported for compatibility to prior releases. These keywords are non-standard
|
|
and should not be used:</p>
|
|
<ul>
|
|
<li>The keywords VARIANT and NOT VARIANT can be used as synonyms for NOT DETERMINISTIC
|
|
and DETERMINISTIC.</li>
|
|
<li>The keywords NULL CALL and NOT NULL CALL can be used as synonyms for CALLED
|
|
ON NULL INPUT and RETURNS NULL ON NULL INPUT.</li>
|
|
<li>DYNAMIC RESULT SET, RESULT SETS, and RESULT SET may be used as synonyms
|
|
for DYNAMIC RESULT SETS.</li></ul>
|
|
<a name="wq1284"></a>
|
|
<h3 id="wq1284"><a href="rbafzmst02.htm#ToC_910">Example</a></h3>
|
|
<p>Create an SQL procedure that returns the median staff salary. Return a
|
|
result set containing the name, position, and salary of all employees who
|
|
earn more than the median salary. </p>
|
|
<pre class="xmp"> <span class="bold">CREATE PROCEDURE</span> MEDIAN_RESULT_SET (<span class="bold">OUT</span> medianSalary <span class="bold">DECIMAL</span>(7,2))
|
|
<span class="bold">LANGUAGE SQL
|
|
<span class="bold">DYNAMIC RESULT SETS</span> 1
|
|
BEGIN
|
|
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
|
|
SELECT</span> salary
|
|
<span class="bold">FROM</span> staff
|
|
<span class="bold">ORDER BY</span> salary;
|
|
<span class="bold">DECLARE</span> c2 <span class="bold">CURSOR WITH RETURN FOR
|
|
SELECT</span> name, job, salary
|
|
<span class="bold">FROM</span> staff
|
|
<span class="bold">WHERE</span> salary > medianSalary
|
|
<span class="bold">ORDER BY</span> salary;
|
|
<span class="bold">DECLARE EXIT HANDLER FOR NOT FOUND
|
|
SET</span> medianSalary = 6666;
|
|
<span class="bold">SET</span> medianSalary = 0;
|
|
<span class="bold">SELECT COUNT(*) INTO</span> v_numRecords <span class="bold">FROM STAFF</span>;
|
|
<span class="bold">OPEN </span>c1;
|
|
<span class="bold">WHILE </span>v_counter < (v_numRecords / 2 + 1)
|
|
<span class="bold">DO FETCH</span> c1 <span class="bold">INTO </span>medianSalary;
|
|
<span class="bold">SET </span>v_counter = v_counter + 1;
|
|
<span class="bold">END WHILE;
|
|
CLOSE</span> c1;
|
|
<span class="bold">OPEN </span>c2;
|
|
<span class="bold">END</span></pre><a id="idx2023" name="idx2023"></a><a id="idx2024" name="idx2024"></a>
|
|
<hr /><br />
|
|
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmstcrtpef.htm">Previous Page</a> | <a href="rbafzmstxcschema.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>
|