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

583 lines
36 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="ALTER PROCEDURE (SQL) statement,
ALTER PROCEDURE (SQL), SQL statements, PROCEDURE clause,
in ALTER PROCEDURE (SQL) statement, procedure-name, in ALTER PROCEDURE (SQL),
DETERMINISTIC clause, NOT DETERMINISTIC clause, MODIFIES SQL DATA clause,
READS SQL DATA clause, CONTAINS SQL clause, CALLED ON NULL INPUT clause,
RESULT SETS clause, FENCED clause, NOT FENCED clause, DEBUG MODE clause,
SAVEPOINT LEVEL clause, COMMIT ON RETURN clause, REPLACE clause, IN clause,
OUT clause, INOUT clause, parameter-name, data-type" />
<title>ALTER 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="aprocedures"></a>
<h2 id="aprocedures"><a href="rbafzmst02.htm#ToC_748">ALTER PROCEDURE (SQL)</a></h2><a id="idx1304" name="idx1304"></a><a id="idx1305" name="idx1305"></a>
<p>The ALTER PROCEDURE (SQL) statement alters a procedure at the current server.</p>
<a name="wq1047"></a>
<h3 id="wq1047"><a href="rbafzmst02.htm#ToC_749">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="wq1048"></a>
<h3 id="wq1048"><a href="rbafzmst02.htm#ToC_750">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>For the procedure identified in the statement:
<ul>
<li>The ALTER privilege for the procedure, and</li>
<li>The system authority *EXECUTE on the library containing the procedure.</li></ul></li>
<li>Administrative authority</li></ul>
<p>If a distinct type is referenced in a <var class="pv">parameter-declaration</var>,
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="wq1049"></a>
<h3 id="wq1049"><a href="rbafzmst02.htm#ToC_751">Syntax</a></h3>
<a href="rbafzmstaprocedures.htm#synasprocedure"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn244.htm"
border="0" /></span><a href="#skipsyn-243"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>>>-ALTER-------------------------------------------------------->
>--+-PROCEDURE--<span class="italic">procedure-name</span>--+--------------------------+-+-->
| '-(--+----------------+--)-' |
| '-<span class="italic">parameter-type</span>-' |
'-SPECIFIC PROCEDURE--<span class="italic">specific-name</span>-----------------------'
.-ALTER-.
>--+-+-------+--<span class="italic">option-list</span>---------+-------------------------->&lt;
'-REPLACE--<span class="italic">routine-specification</span>-'
routine-specification:
|--+-------------------------------------+--+-------------+----->
'-(--+---------------------------+--)-' '-<span class="italic">option-list</span>-'
| .-,---------------------. |
| V | |
'---<span class="italic">parameter-declaration</span>-+-'
>--+----------------------+--<span class="italic">SQL-routine-body</span>-------------------|
'-<span class="italic">SET OPTION-statement</span>-'
parameter-declaration:
.-IN----.
|--+-------+--<span class="italic">parameter-name</span>--<span class="italic">data-type</span>-------------------------|
+-OUT---+
'-INOUT-'
parameter-type:
|----<span class="italic">data-type</span>--+------------+----------------------------------|
'-AS LOCATOR-'
data-type:
|--+-<span class="italic">built-in-type</span>------+---------------------------------------|
'-<span class="italic">distinct-type-name</span>-'
option-list:
.-NOT DETERMINISTIC-. (1) .-MODIFIES SQL DATA-.
|--+-------------------+-------+-------------------+------------>
'-DETERMINISTIC-----' +-READS SQL DATA----+
'-CONTAINS SQL------'
.-CALLED ON NULL INPUT-. .-DYNAMIC RESULT SETS 0--------.
>--+----------------------+--+------------------------------+--->
'-DYNAMIC RESULT SETS--<span class="italic">integer</span>-'
.-FENCED-----.
>--+---------------------+--+------------+---------------------->
+-ALLOW DEBUG MODE----+ '-NOT FENCED-'
+-DISABLE DEBUG MODE--+
'-DISALLOW DEBUG MODE-'
.-OLD SAVEPOINT LEVEL-. .-<span>COMMIT ON RETURN NO</span>--.
>--+---------------------+--+----------------------+------------|
'-NEW SAVEPOINT LEVEL-' '-<span>COMMIT ON RETURN YES</span>-'
</pre>
<a name="skipsyn-243" id="skipsyn-243"></a>
<a name="wq1050"></a>
<div class="notelisttitle" id="wq1050">Notes:</div>
<ol type="1">
<li>The clauses in the <var class="pv">option-list</var> can be specified
in any order.</li>
</ol>
<a name="wq1052"></a>
<div class="fignone" id="wq1052">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn245.htm"
border="0" /></span><a href="#skipsyn-244"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>SQL-routine-body:
|--+-<span><span class="italic">SQL-control-statement</span></span>-----------------------+--------------|
+-<span><span><span class="italic">ALLOCATE DESCRIPTOR-statement</span></span>---------------+
+-<span><span class="italic">ALTER PROCEDURE (External)-statement</span></span>--------+
+-<span><span class="italic">ALTER SEQUENCE-statement</span></span>--------------------+
+-<span><span class="italic">ALTER TABLE-statement</span></span>-----------------------+
+-<span><span class="italic">COMMENT-statement</span></span>---------------------------+
+-<span><span class="italic">COMMIT-statement</span></span>----------------------------+
+-<span><span class="italic">CONNECT-statement</span></span>---------------------------+
+-<span><span class="italic">CREATE ALIAS-statement</span></span>----------------------+
+-<span><span class="italic">CREATE DISTINCT TYPE-statement</span></span>--------------+
+-<span><span class="italic">CREATE FUNCTION (External Scalar)-statement</span></span>-+
+-<span><span class="italic">CREATE FUNCTION (External Table)-statement</span></span>--+
+-<span><span class="italic">CREATE FUNCTION (Sourced)-statement</span></span>---------+
+-<span><span class="italic">CREATE INDEX-statement</span></span>----------------------+
+-<span><span class="italic">CREATE PROCEDURE (External)-statement</span></span>-------+
+-<span><span class="italic">CREATE SCHEMA-statement</span></span>---------------------+
+-<span><span class="italic">CREATE SEQUENCE-statement</span></span>-------------------+
+-<span><span class="italic">CREATE TABLE-statement</span></span>----------------------+
+-<span><span class="italic">CREATE VIEW-statement</span></span>-----------------------+
+-<span><span><span class="italic">DEALLOCATE DESCRIPTOR-statement</span></span>-------------+
+-<span><span class="italic">DECLARE GLOBAL TEMPORARY TABLE-statement</span></span>----+
+-<span><span class="italic">DELETE-statement</span></span>----------------------------+
+-<span><span><span class="italic">DESCRIBE-statement</span></span>--------------------------+
+-<span><span><span class="italic">DESCRIBE INPUT-statement</span></span>--------------------+
+-<span><span><span class="italic">DESCRIBE TABLE-statement</span></span>--------------------+
+-<span><span class="italic">DISCONNECT-statement</span></span>------------------------+
+-<span><span class="italic">DROP-statement</span></span>------------------------------+
+-<span><span class="italic">EXECUTE IMMEDIATE-statement</span></span>-----------------+
+-<span><span><span class="italic">GET DESCRIPTOR-statement</span></span>--------------------+
+-<span><span class="italic">GRANT-statement</span></span>-----------------------------+
+-<span><span class="italic">INSERT-statement</span></span>----------------------------+
+-<span><span class="italic">LABEL-statement</span></span>-----------------------------+
+-<span><span class="italic">LOCK TABLE-statement</span></span>------------------------+
+-<span><span class="italic">REFRESH TABLE-statement</span></span>---------------------+
+-<span><span class="italic">RELEASE-statement</span></span>---------------------------+
+-<span><span class="italic">RELEASE SAVEPOINT-statement</span></span>-----------------+
+-<span><span class="italic">RENAME-statement</span></span>----------------------------+
+-<span><span class="italic">REVOKE-statement</span></span>----------------------------+
+-<span><span class="italic">ROLLBACK-statement</span></span>--------------------------+
+-<span><span class="italic">SAVEPOINT-statement</span></span>-------------------------+
+-<span><span class="italic">SELECT INTO-statement</span></span>-----------------------+
+-<span><span class="italic">SET CONNECTION-statement</span></span>--------------------+
+-<span><span><span class="italic">SET CURRENT DEBUG MODE-statement</span></span>------------+
+-<span><span><span class="italic">SET CURRENT DEGREE-statement</span></span>----------------+
+-<span><span><span class="italic">SET DESCRIPTOR-statement</span></span>--------------------+
+-<span><span class="italic">SET ENCRYPTION PASSWORD-statement</span></span>-----------+
+-<span><span class="italic">SET PATH-statement</span></span>--------------------------+
+-<span><span class="italic">SET RESULT SETS-statement</span></span>-------------------+
+-<span><span class="italic">SET SCHEMA-statement</span></span>------------------------+
+-<span><span class="italic">SET TRANSACTION-statement</span></span>-------------------+
+-<span><span class="italic">UPDATE-statement</span></span>----------------------------+
'-<span><span class="italic">VALUES INTO-statement</span></span>-----------------------'
</span></span></span></span></span></span></span></span></span></pre>
<a name="skipsyn-244" id="skipsyn-244"></a></div>
<a name="wq1053"></a>
<div class="fignone" id="wq1053">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn246.htm"
border="0" /></span><a href="#skipsyn-245"><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-245" id="skipsyn-245"></a></div>
<a name="synasprocedure"></a>
<h3 id="synasprocedure"><a href="rbafzmst02.htm#ToC_752">Description</a></h3>
<p></p>
<dl class="parml">
<dt class="bold">PROCEDURE or SPECIFIC PROCEDURE</dt><a id="idx1306" name="idx1306"></a><a id="idx1307" name="idx1307"></a>
<dd>Identifies the procedure to alter. <span class="italic">procedure-name</span> must identify a procedure that exists at the current server.
<p>The
specified procedure is altered. The owner of the procedure and all privileges
on the procedure are preserved.</p>
<dl class="parml">
<dt class="bold">PROCEDURE <var class="pv">procedure-name</var></dt>
<dd> Identifies the procedure by its name. The <var class="pv">procedure-name</var> must
identify exactly one procedure. The procedure may have any number of parameters
defined for it. If there is more than one procedure of the specified name
in the specified or implicit schema, an error is returned.
</dd>
<dt class="bold">PROCEDURE <var class="pv">procedure-name (parameter-type,...)</var></dt>
<dd>Identifies the procedure by its procedure signature, which
uniquely identifies the procedure. The <var class="pv">procedure-name (parameter-type,...)</var> must identify a procedure with the specified procedure signature. The
specified parameters must match the data types in the corresponding position
that were specified when the procedure was created. The number of data types
and the logical concatenation of the data types is used to identify the specific
procedure instance which is being altered. Synonyms for data types are considered
a match.
<p>If <var class="pv">procedure-name()</var> is specified, the procedure identified
must have zero parameters.</p>
<dl class="parml">
<dt class="bold"><var class="pv">procedure-name</var></dt>
<dd>Identifies the name of the procedure.
</dd>
<dt class="bold"><var class="pv">(parameter-type,...)</var></dt>
<dd>Identifies the parameters of the procedure.
<p>If an unqualified distinct
type name is specified, the database manager searches the SQL path to resolve
the schema name for the distinct type.</p>
<p>For data types that have a length,
precision, or scale attribute, use one of the following:</p>
<ul>
<li>Empty parenthesis indicates that the database manager ignores the attribute
when determining whether the data types match. For example, DEC() will be
considered a match for a parameter of a procedure defined with a data type
of DEC(7,2). However, FLOAT cannot be specified with empty parenthesis because
its precision value indicates a specific data type (REAL or DOUBLE).</li>
<li>If a specific value for a length, precision, or scale attribute is specified,
the value must exactly match the value that was specified (implicitly or explicitly)
in the CREATE PROCEDURE statement. If the data type is FLOAT, the precision
does not have to exactly match the value that was specified because matching
is based on the data type (REAL or DOUBLE).</li>
<li>If length, precision, or scale is not explicitly specified, and empty
parentheses are not specified, the default attributes of the data type are
implied. The implicit length must exactly match the value that was specified
(implicitly or explicitly) in the CREATE PROCEDURE statement.</li></ul>
<p>Specifying the FOR DATA clause or CCSID clause is optional. Omission
of either clause indicates that the database manager ignores the attribute when determining
whether the data types match. If either clause is specified, it must match
the value that was implicitly or explicitly specified in the CREATE PROCEDURE
statement.</p>
</dd>
<dt class="bold">AS LOCATOR</dt>
<dd>Specifies that the procedure is defined to receive a locator for this
parameter. If AS LOCATOR is specified, the data type must be a LOB or a distinct
type based on a LOB.
</dd>
</dl>
</dd>
<dt class="bold">SPECIFIC PROCEDURE <var class="pv">specific-name</var></dt>
<dd>Identifies the procedure by its specific name. The <var class="pv">specific-name</var> must identify a specific procedure that exists at the current server.
</dd>
</dl>
</dd>
<dt class="bold">ALTER <var class="pv">option-list</var></dt>
<dd>Indicates that one or more of the options of the procedure are to be
altered. If ALTER PROCEDURE ALTER <var class="pv">option-list</var> is specified and an
option is not specified, the value from the existing procedure definition
is used.
<dl class="parml">
<dt class="bold">NOT DETERMINISTIC <span class="base">or</span> DETERMINISTIC</dt><a id="idx1308" name="idx1308"></a><a id="idx1309" name="idx1309"></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">MODIFIES SQL DATA, READS SQL DATA, CONTAINS SQL, <span class="base">or</span> NO SQL</dt>
<dd><span>Specifies the classification of SQL statements that this procedure,
or any routine called by this procedure, can execute. The database manager
verifies that the SQL statements issued by the procedure and all routines
called by the procedure are consistent with this specification. For the classification
of each statement, see <a href="rbafzmstaccind.htm#accind">SQL statement data access indication in routines</a>.</span>
<dl class="parml">
<dt class="bold">MODIFIES SQL DATA </dt><a id="idx1310" name="idx1310"></a>
<dd>Specifies that the procedure can execute any SQL statement except statements
that are not supported in procedures.
</dd>
<dt class="bold">READS SQL DATA</dt><a id="idx1311" name="idx1311"></a>
<dd>Specifies that the procedure can execute statements with a data access
classification of READS SQL DATA or CONTAINS SQL.
</dd>
<dt class="bold">CONTAINS SQL</dt><a id="idx1312" name="idx1312"></a>
<dd>Specifies that the procedure can only execute statements with a data
access classification of CONTAINS SQL.
</dd>
</dl>
</dd>
<dt class="bold">CALLED ON NULL INPUT</dt><a id="idx1313" name="idx1313"></a>
<dd>Specifies that the procedure will be called if any, or all, parameter
values are null.
</dd>
<dt class="bold">DYNAMIC RESULT SETS <var class="pv">integer</var></dt><a id="idx1314" name="idx1314"></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 result sets returned
is the minimum of the number of results 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 a 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 both the following are true: </p>
<ul>
<li>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, and</li>
<li>the external program does not have an attribute of ACTGRP(*NEW).</li></ul><p class="indatacontent">For more information about result sets see <a href="rbafzmsthsetrs.htm#hsetrs">SET RESULT SETS</a>.</p>
</dd>
<dt class="bold">FENCED <span class="base">or</span> NOT FENCED</dt><a id="idx1315" name="idx1315"></a><a id="idx1316" name="idx1316"></a>
<dd>This parameter is allowed for compatibility with other products and
is not used by DB2 UDB for iSeries.
</dd>
<dt class="bold">DISALLOW DEBUG MODE, ALLOW DEBUG MODE, <span class="base">or</span> DISABLE
DEBUG MODE</dt><a id="idx1317" name="idx1317"></a>
<dd><span>Indicates whether the procedure can be debugged by the Unified Debugger.
If DEBUG MODE is specified, a DBGVIEW option in the SET OPTION statement must
not be specified.</span>
<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 can 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">OLD SAVEPOINT LEVEL <span class="base">or</span> NEW SAVEPOINT LEVEL</dt><a id="idx1318" name="idx1318"></a>
<dd>Specifies whether a new savepoint level is to be created on entry to
the procedure.
<dl class="parml">
<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.
</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 within the procedure will not conflict with any existing
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><a id="idx1319" name="idx1319"></a>
<dd>Specifies whether the database manager commits the transaction immediately
on return from the procedure.
<dl class="parml">
<dt class="bold">NO</dt>
<dd>The database manager does not issue a commit when the procedure returns.
</dd>
<dt class="bold">YES</dt>
<dd>The database manager issues a commit when 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 must have been defined as WITH HOLD to be usable
after the commit.</p>
</dd>
</dl>
</dd>
</dl>
</dd>
<dt class="bold">REPLACE <var class="pv">routine-specification</var></dt><a id="idx1320" name="idx1320"></a>
<dd>Indicates that the existing procedure definition, including options
and parameters, is to be replaced by those specified in this statement. The
values of all options are replaced when a procedure is replaced. If an option
is not specified, the same default is used as when a new SQL procedure is
created, for more information see <a href="rbafzmstcrtpsf.htm#crtpsf">CREATE PROCEDURE (SQL)</a>.
</dd>
<dt class="bold">(<var class="pv">parameter-declaration</var>,...) </dt>
<dd>Specifies the number of parameters of the procedure, the
data type of each parameter, and the name of each parameter. A parameter
for a procedure can be used for input only, for output only, or for both input
and output.
<p>The maximum number of parameters allowed in an SQL procedure
is 1024.</p>
<dl class="parml">
<dt class="bold">IN</dt><a id="idx1321" name="idx1321"></a>
<dd>Identifies the parameter as an input parameter to the procedure.
</dd>
<dt class="bold">OUT</dt><a id="idx1322" name="idx1322"></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="idx1323" name="idx1323"></a>
<dd>Identifies the parameter as both an input and output parameter for the
procedure. If the parameter is not set within the procedure, its input value
is returned.
</dd>
<dt class="bold"><var class="pv">parameter-name</var></dt><a id="idx1324" name="idx1324"></a>
<dd>Names the parameter for use as an SQL variable. 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="idx1325" name="idx1325"></a>
<dd>Specifies the data type of the parameter. 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.
</dd>
</dl>
</dd>
<dt class="bold"><var class="pv">option-list</var> </dt>
<dd>List of options for the procedure being altered. These options are the
same ones that are listed above under ALTER <var class="pv">option-list</var>. If a specific
option is not specified, the same default that is used when a new procedure
is created is used. For more information see <a href="rbafzmstcrtpsf.htm#crtpsf">CREATE PROCEDURE (SQL)</a>.
</dd>
<dt class="bold"><var class="pv">SQL-routine-body</var></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="wq1054"></a>
<h3 id="wq1054"><a href="rbafzmst02.htm#ToC_753">Notes</a></h3>
<p><span class="bold">General considerations for defining or replacing procedures:</span> See CREATE PROCEDURE for general information on defining a procedure.
ALTER PROCEDURE (SQL) allows individual attributes or the routine specification
to be altered while preserving the privileges on the procedure.</p>
<p><span class="bold">Alter Procedure Replace considerations:</span> When an SQL
procedure is replaced, 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 ALTER PROCEDURE (SQL) statement
is executed. The program is created with ACTGRP(*CALLER).</p>
<p>When an SQL procedure is altered, a new *PGM object is created
and 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>The specific 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">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="wq1055"></a>
<h3 id="wq1055"><a href="rbafzmst02.htm#ToC_754">Examples</a></h3>
<p>Modify the definition for an SQL procedure so that SQL changes are committed
on return from the SQL procedure.</p>
<pre class="xmp"> <span class="bold">ALTER PROCEDURE</span> UPDATE_SALARY_2
<span class="bold">ALTER COMMIT ON RETURN YES</span></pre>
<hr /><br />
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmstaproceduree.htm">Previous Page</a> | <a href="rbafzmstasequence.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>