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

369 lines
27 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="description, functions, types, function,
built-in function, built-in, user-defined, user-defined function,
UDF (user-defined function), SQL, external, sourced, column, column function,
aggregate, aggregate function, scalar, scalar function, table, table function,
syntax, function reference, function invocation, resolution, function resolution,
SQL path, path, best fit, invocation" />
<title>Functions</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="ch2function"></a>
<h2 id="ch2function"><a href="rbafzmst02.htm#ToC_244">Functions</a></h2><a id="idx623" name="idx623"></a>
<p>A <span class="italic">function</span> is an operation denoted by a function
name followed by one or more operands that are enclosed in parentheses. It
represents a relationship between a set of input values and a set of result
values. The input values to a function are called <span class="italic">arguments</span>. For example, a function can be passed two input arguments that have
date and time data types and return a value with a timestamp data type as
the result.</p>
<a name="wq325"></a>
<h3 id="wq325"><a href="rbafzmst02.htm#ToC_245">Types of functions</a></h3><a id="idx624" name="idx624"></a><a id="idx625" name="idx625"></a><a id="idx626" name="idx626"></a><a id="idx627" name="idx627"></a><a id="idx628" name="idx628"></a><a id="idx629" name="idx629"></a><a id="idx630" name="idx630"></a><a id="idx631" name="idx631"></a><a id="idx632" name="idx632"></a><a id="idx633" name="idx633"></a><a id="idx634" name="idx634"></a><a id="idx635" name="idx635"></a><a id="idx636" name="idx636"></a><a id="idx637" name="idx637"></a><a id="idx638" name="idx638"></a>
<p>There are several ways to classify functions. One way to classify functions
is as built-in, user-defined, or generated user-defined functions for distinct
types. </p>
<ul>
<li><span class="italic">Built-in functions</span> are functions that
come with the database manager. These functions provide a single-value result. Built-in
functions include operator functions such as "+", aggregate functions such
as AVG, and scalar functions such as SUBSTR. For a list of the built-in aggregate
and scalar functions and information on these functions, see <a href="rbafzmstch2func.htm#ch2func">Built-in functions</a>.
<p>The <span class="italic">built-in functions</span> are part of schema
QSYS2. <sup class="fn"><a id="wq326" name="wq326" href="rbafzmstch2function.htm#wq327">33</a></sup></p></li>
<li><span class="italic">User-defined functions</span> are functions
that are created using the CREATE FUNCTION statement and registered to the database manager in
catalog table QSYS2.SYSROUTINES and catalog view QSYS2.SYSFUNCS. For more
information, see <a href="rbafzmstcreatef.htm#createf">CREATE FUNCTION</a>. These functions allow users to extend
the function of the database manager by adding their own or third party vendor
function definitions.
<p>A user-defined function is either an <span class="italic">SQL</span>, <span class="italic">external</span>, or <span class="italic">sourced</span> function. An SQL function is defined to the database using only SQL
statements. An external function is defined to the database with a reference
to an external program or service program that is executed when the function
is invoked. A sourced function is defined to the database with a reference
to a built-in function or another user-defined function. Sourced functions
can be used to extend built-in aggregate and scalar functions for use on distinct
types.</p>
<p>A user-defined function resides in the schema in which it was
created. The schema cannot be QSYS, QSYS2, or QTEMP.</p></li>
<li><span class="italic">Generated user-defined functions for distinct types</span> are functions that the database manager automatically generates when
a distinct type is created using the CREATE DISTINCT TYPE statement. These
functions support casting from the distinct type to the source type and from
the source type to the distinct type. The ability to cast between the data
types is important because a distinct type is compatible only with itself.
<p>The generated cast functions reside in the same schema as the distinct type
for which they were created. The schema cannot be QSYS, QSYS2, or QTEMP. For
more information about the functions that are generated for a distinct type,
see <a href="rbafzmstcrtudt.htm#crtudt">CREATE DISTINCT TYPE</a>.</p></li></ul>
<p>Another way to classify functions is as aggregate, scalar, or
table functions, depending on the input data values and result values.</p>
<ul><a id="idx639" name="idx639"></a><a id="idx640" name="idx640"></a><a id="idx641" name="idx641"></a><a id="idx642" name="idx642"></a>
<li>An <span class="italic">aggregate function</span> receives a set of values
for each argument (such as the values of a column) and returns a single-value
result for the set of input values. Aggregate functions are sometimes called <span class="italic">column functions</span>. Built-in functions and user-defined
sourced functions can be aggregate functions.</li><a id="idx643" name="idx643"></a><a id="idx644" name="idx644"></a>
<li>A <span class="italic">scalar function</span> receives a single value for
each argument and returns a single-value result. Built-in functions and user-defined
functions can be scalar functions. Generated user-defined functions for distinct
types are also scalar functions.</li><a id="idx645" name="idx645"></a><a id="idx646" name="idx646"></a>
<li>A <span class="italic">table function</span> returns a table for the set of
arguments it receives. Each argument is a single value. A table function can
only be referenced in the FROM clause of a subselect. A table function can
be defined as an external function or as an SQL function, but a table function
cannot be a sourced function.
<p>Table functions can be used to apply SQL language
processing power to data that is not DB2&reg; data or to convert such data into a DB2 table.
For example, a table function can take a file and convert it to a table, get
data from the Web and tabularize it, or access a Lotus&reg; Notes&reg; database and return information about
email messages.</p></li></ul>
<a name="funinv2"></a>
<h3 id="funinv2"><a href="rbafzmst02.htm#ToC_246">Function invocation</a></h3><a id="idx647" name="idx647"></a><a id="idx648" name="idx648"></a><a id="idx649" name="idx649"></a>
<p>Each reference to a scalar or aggregate function (either built-in
or user-defined) conforms to the following syntax: <sup class="fn"><a id="wq328" name="wq328" href="rbafzmstch2function.htm#wq329">34</a></sup></p>
<a href="rbafzmstch2function.htm#synfunbuilt"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<a name="wq330"></a>
<div class="fignone" id="wq330">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn18.htm"
border="0" /></span><a href="#skipsyn-17"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>function-invocation:
(1)
|--<span class="italic">function-name</span>--(--+----------+-------+----------------+--)---|
+-ALL------+ | .-,----------. |
'-DISTINCT-' | V | |
'---<span class="italic">expression</span>-+-'
</pre>
<a name="skipsyn-17" id="skipsyn-17"></a>
<a name="wq331"></a>
<div class="notelisttitle" id="wq331">Notes:</div>
<ol type="1">
<li>The ALL or DISTINCT keyword can be specified only for
an aggregate function or a user-defined function that is sourced on an aggregate
function.</li>
</ol></div>
<a name="synfunbuilt"></a>
<p id="synfunbuilt">Each reference to a table function conforms to the following
syntax:</p>
<a href="rbafzmstch2function.htm#synfuntable"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<a name="wq333"></a>
<div class="fignone" id="wq333">
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn19.htm"
border="0" /></span><a href="#skipsyn-18"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>>>-TABLE--(--<span class="italic">function-name</span>--(--+----------------+--)--)--<span class="italic">correlation-clause</span>->&lt;
| .-,----------. |
| V | |
'---<span class="italic">expression</span>-+-'
</pre>
<a name="skipsyn-18" id="skipsyn-18"></a></div>
<a name="synfuntable"></a>
<p id="synfuntable">In the above syntax, <var class="pv">expression</var> is
the same as it is for a scalar or aggregate function. See <a href="rbafzmstch2expr.htm#ch2expr">Expressions</a> for
other rules for <var class="pv">expression</var>.</p>
<p>When the function is invoked, the value of each of its parameters is assigned,
using storage assignment, to the corresponding parameter of the function.
Control is passed to external functions according to the calling conventions
of the host language. When execution of a user-defined aggregate or scalar
function is complete, the result of the function is assigned, using storage
assignment, to the result data type. For details on the assignment rules,
see <a href="rbafzmstch2bas.htm#ch2bas">Assignments and comparisons</a>.</p>
<p>Table functions can be referenced only in the FROM clause of a subselect.
For more details on referencing a table function, see the description of the
FROM clause in <a href="rbafzmstsubselect.htm#fromclause">from-clause</a>.</p>
<a name="funcres"></a>
<h3 id="funcres"><a href="rbafzmst02.htm#ToC_247">Function resolution</a></h3><a id="idx650" name="idx650"></a>
<p>A function is invoked by its function name, which is implicitly or explicitly
qualified with a schema name, followed by parentheses that enclose the arguments
to the function. Within the database, each function is uniquely identified
by its function signature, which is its schema name, function name, the number
of parameters, and the data types of the parameters. Thus, a schema can contain
several functions that have the same name but each of which have a different
number of parameters, or parameters with different data types. Or, a function
with the same name, number of parameters, and types of parameters can exist
in multiple schemas. When any function is invoked, the database manager must determine
which function to execute. This process is called <var class="pv">function resolution</var>.</p>
<p>Function resolution is similar for functions that are invoked with a qualified
or unqualified function name with the exception that for an unqualified name, the database manager needs
to search more than one schema.</p>
<ul>
<li><span class="italic">Qualified function resolution:</span> When a function
is invoked with a function name and a schema name, the database manager only searches the
specified schema to resolve which function to execute. The database manager
selects candidate functions based on the following criteria:
<ul>
<li>The name of the function instance matches the name in the function invocation.</li>
<li>The number of input parameters in the function instance matches the number
of arguments in the function invocation.</li>
<li>The authorization ID of the statement must have the EXECUTE privilege
to the function instance.</li>
<li>The data type of each input argument of the function invocation matches
or is <span class="italic">promotable</span> to the data type of the corresponding
parameter of the function instance.</li></ul>
<p>If no function in the schema meets these criteria, an error is returned.
If a function is selected, its successful use depends on it being invoked
in a context in which the returned result is allowed. For example, if the
function returns an integer data type where a character data type is required,
or returns a table where a table is not allowed, an error is returned.</p></li>
<li><span class="italic">Unqualified function resolution:</span> When a function
is invoked with only a function name, the database manager needs to search more than one
schema to resolve the function instance to execute. The SQL path contains
the list of schemas to search. For each schema in the SQL path (see <a href="rbafzmstch2nam.htm#path">SQL path</a>), the database manager selects candidate functions based on the following
criteria:
<ul>
<li>The name of the function instance matches the name in the function invocation.</li>
<li>The number of input parameters in the function instance matches the number
of function arguments in the function invocation.</li>
<li>The authorization ID of the statement must have the EXECUTE privilege
to the function instance.</li>
<li>The data type of each input argument of the function invocation matches
or is <span class="italic">promotable</span> to the data type of the corresponding
parameter of the function instance.</li></ul>
<p>If no function in the schema meets these criteria, an error is returned.
If a function is selected, its successful use depends on it being invoked
in a context in which the returned result is allowed. For example, if the
function returns an integer data type where a character data type is required,
or returns a table where a table is not allowed, an error is returned.</p></li></ul><a id="idx651" name="idx651"></a><a id="idx652" name="idx652"></a>
<p>After the database manager identifies the candidate functions, it selects the candidate
with the best fit as the function instance to execute (see <a href="rbafzmstch2function.htm#bestfit">Determining the best fit</a>).
If more than one schema contains the function instance with the best fit (the
function signatures are identical except for the schema name), the database manager selects
the function whose schema is earliest in the SQL path.</p>
<p>Function resolution applies to all functions, including built-in functions.
Built-in functions logically exist in schema QSYS2. If schema QSYS2 is not
explicitly specified in the SQL path, the schema is implicitly assumed at
the front of the path. Therefore, when an unqualified function name is specified,
ensure that the path is specified so that the intended function is selected.</p>
<p>In a CREATE VIEW statement, function resolution occurs at the time the
view is created. If another function with the same name is subsequently created,
the view is not affected, even if the new function is a better fit than the
one chosen at the time the view was created.</p>
<a name="bestfit"></a>
<h3 id="bestfit"><a href="rbafzmst02.htm#ToC_248">Determining the best fit</a></h3><a id="idx653" name="idx653"></a>
<p>There might be more than one function with the same name that
is a candidate for execution. In that case, the database manager determines which function
is the best fit for the invocation by comparing the argument and parameter
data types. Note that the data type of the result of the function or the type
of function (aggregate, scalar, or table) under consideration does not enter
into this determination.</p>
<p>If the data types of all the parameters for a given function are the same
as those of the arguments in the function invocation, that function is the
best fit. If there is no exact match, the database manager compares the data types in the
parameter lists from left to right, using the following method: </p>
<ol type="1">
<li>Compare the data type of the first argument in the function invocation
to the data type of the first parameter in each function. (Any length, precision,
scale, and CCSID attributes of the data types are not considered in the comparison.)</li>
<li>For this argument, if one function has a data type that fits the function
invocation better than the data types in the other functions, that function
is the best fit. The precedence list for the promotion of data types in <a href="rbafzmstpromo.htm#promo">Promotion of data types</a> shows the data types that fit each data type in best-to-worst
order.</li>
<li>If the data type of the first parameter for more than one candidate function
fits the function invocation equally well, repeat this process for the next
argument of the function invocation. Continue for each argument until a best
fit is found.</li></ol>
<p>The following examples illustrate function resolution.</p>
<p><span class="italic">Example 1:</span> Assume that MYSCHEMA contains two functions,
both named FUNA, that were created with these partial CREATE FUNCTION statements.</p>
<pre class="xmp"> <span class="bold">CREATE FUNCTION</span> MYSCHEMA.FUNA <span class="bold">(VARCHAR(</span>10<span class="bold">), INT, DOUBLE)</span> ...
<span class="bold">CREATE FUNCTION</span> MYSCHEMA.FUNA <span class="bold">(VARCHAR(</span>10<span class="bold">), REAL, DOUBLE)</span> ... </pre>
<p>Also assume that a function with three arguments of data types VARCHAR(10),
SMALLINT, and DECIMAL is invoked with a qualified name: </p>
<pre class="xmp"> MYSCHEMA.FUNA<span class="bold">(</span> VARCHARCOL, SMALLINTCOL, DECIMALCOL <span class="bold">)</span> ...
</pre>
<p>Both MYSCHEMA.FUNA functions are candidates for this function invocation
because they meet the criteria specified in <a href="rbafzmstch2function.htm#funcres">Function resolution</a>. The data
types of the first parameter for the two function instances in the schema,
which are both VARCHAR, fit the data type of the first argument of the function
invocation, which is VARCHAR, equally well. However, for the second parameter,
the data type of the first function (INT) fits the data type of the second
argument (SMALLINT) better than the data type of second function (REAL). Therefore, the database manager selects
the first MYSCHEMA.FUNA function as the function instance to execute.</p>
<p><span class="italic">Example 2:</span> Assume that functions were created with
these partial CREATE FUNCTION statements: </p>
<pre class="xmp"> 1. <span class="bold">CREATE FUNCTION</span> SMITH.ADDIT <span class="bold">(CHAR(</span>5<span class="bold">), INT, DOUBLE)</span> ...
2. <span class="bold">CREATE FUNCTION</span> SMITH.ADDIT <span class="bold">(INT, INT, DOUBLE)</span> ...
3. <span class="bold">CREATE FUNCTION</span> SMITH.ADDIT <span class="bold">(INT, INT, DOUBLE, INT)</span> ...
4. <span class="bold">CREATE FUNCTION</span> JOHNSON.ADDIT <span class="bold">(INT, DOUBLE, DOUBLE)</span> ...
5. <span class="bold">CREATE FUNCTION</span> JOHNSON.ADDIT <span class="bold">(INT, INT, DOUBLE)</span> ...
6. <span class="bold">CREATE FUNCTION</span> TODD.ADDIT <span class="bold">(REAL)</span> ...
7. <span class="bold">CREATE FUNCTION</span> TAYLOR.SUBIT <span class="bold">(INT, INT, DECIMAL)</span> ... </pre>
<p>Also assume that the SQL path at the time an application invokes a function
is "TAYLOR", "JOHNSON", "SMITH". The function is invoked with three data types
(INT, INT, DECIMAL) as follows:</p>
<pre class="xmp"> <span class="bold">SELECT </span> ... ADDIT<span class="bold">(</span>INTCOL1, INTCOL2, DECIMALCOL<span class="bold">)</span> ...</pre>
<p>Function 5 is chosen as the function instance to execute based on the following
evaluation: </p>
<ul>
<li>Function 6 is eliminated as a candidate because schema TODD is not in
the SQL path.</li>
<li>Function 7 in schema TAYLOR is eliminated as a candidate because it does
not have the correct function name.</li>
<li>Function 1 in schema SMITH is eliminated as a candidate because the INT
data type is not promotable to the CHAR data type of the first parameter of
Function 1.</li>
<li>Function 3 in schema SMITH is eliminated as a candidate because it has
the wrong number of parameters.</li>
<li>Function 2 is a candidate because the data types of its parameters match
or are promotable to the data types of the arguments.</li>
<li>Both Function 4 and 5 in schema JOHNSON are candidates because the data
types of their parameters match or are promotable to the data types of the
arguments. However, Function 5 is chosen as the better candidate because although
the data types of the first parameter of both functions (INT) match the first
argument (INT), the data type of the second parameter of Function 5 (INT)
is a better match of the second argument (INT) than the data type of Function
4 (DOUBLE).</li>
<li>Of the remaining candidates, Function 2 and 5, the database manager selects Function
5 because schema JOHNSON comes before schema SMITH in the SQL path.</li></ul>
<p><span class="italic">Example 3:</span> Assume that functions were created with
these partial CREATE FUNCTION statements: </p>
<pre class="xmp"> 1. <span class="bold">CREATE FUNCTION</span> BESTGEN.MYFUNC <span class="bold">(INT, DECIMAL(</span>9,0<span class="bold">))</span> ...
2. <span class="bold">CREATE FUNCTION</span> KNAPP.MYFUNC <span class="bold">(INT, NUMERIC(</span>8,0<span class="bold">))</span>...
3. <span class="bold">CREATE FUNCTION</span> ROMANO.MYFUNC <span class="bold">(INT, FLOAT)</span> ... </pre>
<p>Also assume that the SQL path at the time an application invokes a function
is "ROMANO", "KNAPP", "BESTGEN". The function is invoked with two data types
(SMALLINT, DECIMAL) as follows:</p>
<pre class="xmp"> <span class="bold">SELECT </span> ... MYFUNC<span class="bold">(</span>SINTCOL1, DECIMALCOL<span class="bold">)</span> ...</pre>
<p>Function 2 is chosen as the function instance to execute based on the following
evaluation: </p>
<ul>
<li>All three functions are candidates for this function invocation because
they meet the criteria specified in <a href="rbafzmstch2function.htm#funcres">Function resolution</a>.</li>
<li>Function 3 in schema ROMANO is eliminated because the second parameter
(FLOAT) is not as good a fit for the second argument (DECIMAL) as the second
parameter of either Function 1 (DECIMAL) or Function 2 (NUMERIC).</li>
<li>The second parameters of Function 1 (DECIMAL) and Function 2 (NUMERIC)
are equally good fits for the second argument (DECIMAL).</li>
<li>Function 2 is finally chosen because "KNAPP" precedes "BESTGEN" in the
SQL path.</li></ul>
<a name="funinv"></a>
<h3 id="funinv"><a href="rbafzmst02.htm#ToC_249">Best fit considerations</a></h3><a id="idx654" name="idx654"></a>
<p>Once the function is selected, there are still possible reasons why the
use of the function may not be permitted. Each function is defined to return
a result with a specific data type. If this result data type is not compatible
within the context in which the function is invoked, an error will occur.
For example, given functions named STEP defined with different data types
as the result:</p>
<pre class="xmp"> STEP<span class="bold">(SMALLINT) RETURNS CHAR(</span>5<span class="bold">)</span>
STEP<span class="bold">(DOUBLE) RETURNS INTEGER</span></pre>
<p>and the following function reference (where S is a SMALLINT column):</p>
<pre class="xmp"> <span class="bold">SELECT</span> ... 3 +STEP<span class="bold">(</span>S<span class="bold">)</span>
&nbsp; </pre>
<p>then, because there is an exact match on argument type, the first STEP
is chosen. An error occurs on the statement because the result type is CHAR(5)
instead of a numeric type as required for an argument of the addition operator.</p>
<p>In cases where the arguments of the function invocation were not an exact
match to the data types of the parameters of the selected function, the arguments
are converted to the data type of the parameter at execution using the same
rules as assignment to columns (see <a href="rbafzmstch2bas.htm#ch2bas">Assignments and comparisons</a>). This includes
the case where precision, scale, length, or CCSID differs between the argument
and the parameter.</p>
<p>An error also occurs in the following examples:</p>
<ul>
<li>The function is referenced in the TABLE clause of a FROM clause,
but the function selected by the function resolution step is a scalar or aggregate
function.</li>
<li>The function referenced in an SQL statement requires a scalar
or aggregate function, but the function selected by the function resolution
step is a table function.</li></ul>
<hr /><div class="fnnum"><a id="wq327" name="wq327" href="rbafzmstch2function.htm#wq326">33</a>.</div>
<div class="fntext"><span class="italic">Built-in functions</span> are implemented internally
by the database manager, so an associated program or service program object does not exist
for a <span class="italic">built-in function</span>. Furthermore, the catalog
does not contain information about <span class="italic">built-in functions</span>.
However, <span class="italic">built-in functions</span> can be treated as if they
exist in QSYS2 and a <span class="italic">built-in function</span> name can be
qualified with QSYS2.</div><div class="fnnum"><a id="wq329" name="wq329" href="rbafzmstch2function.htm#wq328">34</a>.</div>
<div class="fntext">A few functions allow
keywords instead of expressions. For example, the CHAR function allows a list
of keywords to indicate the desired date format. A few functions use keywords
instead of commas in a comma separated list of expressions. For example, the
EXTRACT, TRIM, and POSITION functions use keywords.</div>
<br />
<hr /><br />
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmstch2refvar.htm">Previous Page</a> | <a href="rbafzmstch2expr.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>