ibm-information-center/dist/eclipse/plugins/i5OS.ic.sqlp_5.4.0.1/rbafysummary.htm

155 lines
11 KiB
HTML
Raw Permalink Normal View History

2024-04-02 14:02:31 +00:00
<?xml version="1.0" encoding="UTF-8"?>
<!DOCTYPE html
PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd">
<html lang="en-us" xml:lang="en-us">
<head>
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
<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="DC.Type" content="reference" />
<meta name="DC.Title" content="Summary of function references" />
<meta name="abstract" content="For both qualified and unqualified function references, the function selection algorithm looks at all the applicable functions, both built-in and user-defined functions, that have the given name, the same number of defined parameters as argument, and each parameter identical to or promotable from the type of the corresponding argument." />
<meta name="description" content="For both qualified and unqualified function references, the function selection algorithm looks at all the applicable functions, both built-in and user-defined functions, that have the given name, the same number of defined parameters as argument, and each parameter identical to or promotable from the type of the corresponding argument." />
<meta name="DC.subject" content="UDFs (User-defined functions), summary of function references, function, references, summary for UDFs, general considerations, infix notation, infix notation and UDFs, LOB types, casting, casting, UDFs" />
<meta name="keywords" content="UDFs (User-defined functions), summary of function references, function, references, summary for UDFs, general considerations, infix notation, infix notation and UDFs, LOB types, casting, casting, UDFs" />
<meta name="DC.Relation" scheme="URI" content="rbafyudfuudf.htm" />
<meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" />
<meta name="DC.Rights.Owner" content="(C) Copyright IBM Corporation 1998, 2006" />
<meta name="DC.Format" content="XHTML" />
<meta name="DC.Identifier" content="rbafysummary" />
<meta name="DC.Language" 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. -->
<link rel="stylesheet" type="text/css" href="./ibmdita.css" />
<link rel="stylesheet" type="text/css" href="./ic.css" />
<title>Summary of function references</title>
</head>
<body id="rbafysummary"><a name="rbafysummary"><!-- --></a>
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
<h1 class="topictitle1">Summary of function references</h1>
<div><p>For both qualified and unqualified function references, the function
selection algorithm looks at all the applicable functions, both built-in and
user-defined functions, that have the given name, the same number
of defined parameters as argument, and each parameter identical to or promotable
from the type of the corresponding argument.</p>
<div class="section"><p>Applicable functions means functions in the named schema for a
qualified reference, or functions in the schemas of the function path for
an unqualified reference. The algorithm looks for an exact match, or failing
that, a best match among these functions. The current function path is used,
in the case of an unqualified reference only, as the deciding factor if two
identically good matches are found in different schemas.</p>
</div>
<div class="section"><p>An interesting feature is the fact that function references can
be nested, even references to the same function. This is generally true for
built-in functions as well as UDFs. However, there are some limitations when
column functions are involved. </p>
</div>
<div class="section"><p>Refining an earlier example:</p>
<pre> <strong>CREATE FUNCTION</strong> BLOOP (<strong>INTEGER</strong>) <strong>RETURNS INTEGER</strong> ...
<strong>CREATE FUNCTION</strong> BLOOP (<strong>DOUBLE</strong>) <strong>RETURNS INTEGER</strong> ...</pre>
</div>
<div class="section"><p>Now consider the following statement:</p>
<pre> <strong>SELECT</strong> BLOOP( BLOOP(COLUMN1)) <strong>FROM</strong> T</pre>
</div>
<div class="section"><p>If COLUMN1 is a DECIMAL or DOUBLE column, the inner BLOOP reference
resolves to the second BLOOP defined above. Because this BLOOP returns an
INTEGER, the outer BLOOP resolves to the first BLOOP. </p>
</div>
<div class="section"><p>Alternatively, if COLUMN1 is a SMALLINT or INTEGER column, the
inner BLOOP reference resolves to the first BLOOP defined above. Because
this BLOOP returns an INTEGER, the outer BLOOP also resolves to the first
BLOOP. In this case, you are seeing nested references to the same function. </p>
</div>
<div class="section"><div class="p">A few additional points important for function references are:
<ul><li>You can define a function with the name of one of the SQL operators. For
example, suppose you can attach some meaning to the <samp class="codeph">"+"</samp>
operator for values which have distinct type BOAT. You can define the following
UDF: <pre> <strong>CREATE FUNCTION</strong> "+" (BOAT, BOAT) <strong>RETURNS</strong> ...</pre>
<div class="p">Then
you can write the following valid SQL statement: <pre> <strong>SELECT</strong> "+"(BOAT_COL1, BOAT_COL2)
<strong>FROM</strong> BIG_BOATS
<strong>WHERE</strong> BOAT_OWNER = 'Nelson Mattos' </pre>
</div>
<p>You are
not permitted to overload the built-in conditional operators such as <samp class="codeph">&gt;</samp>, <samp class="codeph">=</samp>,
<samp class="codeph">LIKE</samp>, <samp class="codeph">IN</samp>, and so on, in this way.</p>
</li>
<li>The function selection algorithm does not consider the context of the
reference in resolving to a particular function. Look at these BLOOP functions,
modified a bit from before: <pre> <strong>CREATE FUNCTION</strong> BLOOP (<strong>INTEGER</strong>) <strong>RETURNS INTEGER</strong> ...
<strong>CREATE FUNCTION</strong> BLOOP (<strong>DOUBLE</strong>) <strong>RETURNS CHAR</strong>(10)...</pre>
<div class="p">Now suppose you write the following SELECT statement: <pre> <strong>SELECT</strong> 'ABCDEFG' <strong>CONCAT</strong> BLOOP(SMALLINT_COL) <strong>FROM</strong> T</pre>
</div>
<p>Because the best match, resolved using the SMALLINT argument, is
the first BLOOP defined above, the second operand of the CONCAT resolves to
data type INTEGER. The statement might not return the expected result since
the returned integer will be cast as a VARCHAR before the CONCAT is performed.
If the first BLOOP was not present, the other BLOOP is chosen and the statement
execution is successful. </p>
</li>
<li>UDFs can be defined with parameters or results having any of the LOB types:
BLOB, CLOB, or DBCLOB. The system will materialize the entire LOB value in
storage before calling such a function, even if the source of the value is
a <em>LOB locator</em> host variable. For example, consider the following
fragment of a C language application: <pre> EXEC SQL <strong>BEGIN DECLARE SECTION</strong>;
<strong>SQL TYPE IS CLOB</strong>(150K) clob150K ; /* LOB host var */
<strong>SQL TYPE IS CLOB_LOCATOR</strong> clob_locator1; /* LOB locator host var */
char string[40]; /* string host var */
EXEC SQL <strong>END DECLARE SECTION</strong>; </pre>
<div class="p">Either host variable <samp class="codeph">:clob150K</samp> or <samp class="codeph">:clob_locator1</samp>
is valid as an argument for a function whose corresponding parameter is defined
as <samp class="codeph">CLOB(500K)</samp>. Referring to the FINDSTRING defined in <a href="rbafyudfcfx2.htm#rbafyudfcfx2">Example: String search</a> both of the following are valid
in the program: <pre> ... <strong>SELECT FINDSTRING</strong> (:clob150K, :string) <strong>FROM</strong> ...
... <strong>SELECT FINDSTRING</strong> (:clob_locator1, :string) <strong>FROM</strong> ...</pre>
</div>
</li>
<li>External UDF parameters or results which have one of the LOB types can
be created with the AS LOCATOR modifier. In this case, the entire LOB value
is not materialized before invocation. Instead, a LOB LOCATOR is passed to
the UDF. <p>You can also use this capability on UDF parameters or results
which have a distinct type that is based on a LOB. This capability is limited
to external UDFs. Note that the argument to such a function can be any LOB
value of the defined type; it does not need to be a host variable defined
as one of the LOCATOR types. The use of host variable locators as arguments
is completely unrelated to the use of AS LOCATOR in UDF parameters and result
definitions.</p>
</li>
<li>UDFs can be defined with distinct types as parameters or as the result. DB2<sup>®</sup> will
pass the value to the UDF in the format of the source data type of the distinct
type. <div class="p">Distinct type values that originate in a host variable and which
are used as arguments to a UDF which has its corresponding parameter defined
as a distinct type must be explicitly cast to the distinct type by the user.
There is no host language type for distinct types. DB2's strong typing necessitates
this. Otherwise your results may be ambiguous. So, consider the BOAT distinct
type that is defined over a BLOB that takes an object of type BOAT as its
argument. In the following fragment of a C language application, the host
variable <samp class="codeph">:ship</samp> holds the BLOB value that is to passed to
the BOAT_COST function: <pre> EXEC SQL <strong>BEGIN DECLARE SECTION</strong>;
<strong>SQL TYPE IS BLOB</strong>(150K) ship;
EXEC SQL <strong>END DECLARE SECTION</strong>;</pre>
</div>
<div class="p">Both of the following
statements correctly resolve to the BOAT_COST function, because both cast
the <samp class="codeph">:ship</samp> host variable to type BOAT: <pre> ... <strong>SELECT</strong> BOAT_COST (<strong>BOAT</strong>(:ship)) <strong>FROM</strong> ...
... <strong>SELECT</strong> BOAT_COST (<strong>CAST</strong>(:ship AS BOAT)) <strong>FROM</strong> ...</pre>
</div>
<p>If
there are multiple BOAT distinct types in the database, or BOAT UDFs in other
schema, you must be careful with your function path. Otherwise your results
may be unpredictable. </p>
</li>
</ul>
</div>
</div>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="rbafyudfuudf.htm" title="Scalar and column UDFs can be called within an SQL statement almost everywhere that an expression is valid. Table UDFs can be called in the FROM clause of a SELECT. There are a few restrictions of UDF usage, however.">Use UDFs in SQL statements</a></div>
</div>
</div>
</body>
</html>