878 lines
53 KiB
HTML
878 lines
53 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, predicate, row-value-expression,
|
||
|
basic predicate, basic, quantified predicate, ANY clause, ALL clause,
|
||
|
SOME quantified predicate, quantified, BETWEEN predicate, BETWEEN,
|
||
|
DISTINCT predicate, DISTINCT, EXISTS predicate, EXISTS, IN predicate, IN,
|
||
|
LIKE predicate, LIKE, _ (underscore) in LIKE predicate,
|
||
|
% (percent) in LIKE predicate, in LIKE predicates, mixed data,
|
||
|
double-byte character, single-byte character, ESCAPE clause of LIKE predicate,
|
||
|
NULL predicate, NULL" />
|
||
|
<title>Predicates</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="ch2pred"></a>
|
||
|
<h2 id="ch2pred"><a href="rbafzmst02.htm#ToC_288">Predicates</a></h2><a id="idx752" name="idx752"></a>
|
||
|
<p>A <span class="italic">predicate</span> specifies a condition that is true,
|
||
|
false, or unknown about a given row or group.</p>
|
||
|
<p>The following rules apply to all types of predicates: </p>
|
||
|
<ul>
|
||
|
<li>Predicates are evaluated after the expressions that are operands of the
|
||
|
predicate.</li>
|
||
|
<li>All values specified in the same predicate must be compatible.</li>
|
||
|
<li>The value of a variable may be null (that is, the variable may have a
|
||
|
negative indicator variable).</li>
|
||
|
<li>The CCSID conversion of operands of predicates involving two or more operands
|
||
|
are done according to <a href="rbafzmstch2bas.htm#crcj">Conversion rules for comparison</a>.</li>
|
||
|
<li>Use of a DataLink value is limited to the NULL predicate.</li></ul>
|
||
|
<p><span class="bold">Row-value expression</span>: The operand of several
|
||
|
predicates (basic, quantified, and IN) can be a <span class="italic">row-value-expression</span>:<a id="idx753" name="idx753"></a>
|
||
|
<a href="rbafzmstch2pred.htm#synrve"><img src="c.gif" alt="Click to skip syntax diagram" /></a></p>
|
||
|
<a name="wq387"></a>
|
||
|
<div class="fignone" id="wq387">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn28.htm"
|
||
|
border="0" /></span><a href="#skipsyn-27"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a> .-,----------.
|
||
|
V |
|
||
|
>>-(----<span class="italic">expression</span>-+--)----------------------------------------><
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-27" id="skipsyn-27"></a></div>
|
||
|
<a name="synrve"></a>
|
||
|
<p id="synrve">A <span class="italic">row-value-expression</span> returns
|
||
|
a single row that consists of one or more column values. The values can be
|
||
|
specified as a list of expressions. The number of columns that are returned
|
||
|
by the <span class="italic">row-value-expression</span> is equal to the number
|
||
|
of expressions that are specified in the list.</p>
|
||
|
<a name="baspred"></a>
|
||
|
<h3 id="baspred"><a href="rbafzmst02.htm#ToC_289">Basic predicate</a></h3><a id="idx754" name="idx754"></a><a id="idx755" name="idx755"></a>
|
||
|
<a href="rbafzmstch2pred.htm#synbasic"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
||
|
<a name="wq388"></a>
|
||
|
<div class="fignone" id="wq388">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn29.htm"
|
||
|
border="0" /></span><a href="#skipsyn-28"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a> (1)
|
||
|
>>-+-<span><span class="italic">expression</span></span>--+-<span> = </span>--+-------<span><span class="italic">expression</span></span>----------------------------+-><
|
||
|
| +-<span> <> </span>-+ |
|
||
|
| +-<span> < </span>--+ |
|
||
|
| +-<span> > </span>--+ |
|
||
|
| +-<span> <= </span>-+ |
|
||
|
| '-<span> >= </span>-' |
|
||
|
+-<span>(</span>--<span><span class="italic">row-value-expression</span></span>--<span>)</span>--+-<span> = </span>--+--<span>(</span>--<span><span class="italic">row-value-expression</span></span>--<span>)</span>-+
|
||
|
| '-<span> <> </span>-' |
|
||
|
+-<span><span>(</span>--<span><span><span class="italic">fullselect</span></span>--<span><span>)</span>--+-<span><span> = </span>--+--<span><span>(</span>--<span><span><span class="italic">row-value-expression</span></span>--<span><span>)</span>-----------+
|
||
|
| '-<span><span> <> </span>-' |
|
||
|
'-<span><span>(</span>--<span><span><span class="italic">row-value-expression</span></span>--<span><span>)</span>--+-<span><span> = </span>--+--<span><span>(</span>--<span><span><span class="italic">fullselect</span></span>--<span><span>)</span>-----------'
|
||
|
'-<span><span> <> </span>-'
|
||
|
|
||
|
</span></span></span></span></span></span></span></span></span></span></span></span></span></span></span></span></pre>
|
||
|
<a name="skipsyn-28" id="skipsyn-28"></a>
|
||
|
<a name="wq389"></a>
|
||
|
<div class="notelisttitle" id="wq389">Notes:</div>
|
||
|
<ol type="1">
|
||
|
<li>Other comparison operators are also supported. </li>
|
||
|
</ol></div>
|
||
|
<p>A <span class="italic">basic predicate</span> compares two values
|
||
|
or compares a set of values with another set of values.</p>
|
||
|
<p>When a single <span class="italic">expression</span> is specified
|
||
|
on the left side of the operator, another <span class="italic">expression</span> must
|
||
|
be specified on the right side. The data types of the corresponding expressions
|
||
|
must be compatible. The value of the expression on the left side is compared
|
||
|
with the value of the expression on the right side. If the value of either
|
||
|
operand is null, the result of the predicate is unknown. Otherwise the result
|
||
|
is either true or false.</p>
|
||
|
<p>When a <span class="italic">row-value-expression</span> is specified
|
||
|
on the left side of the operator (= or <>) and another <span class="italic">row-value-expression</span> is specified on the right side of the operator,
|
||
|
both <span class="italic">row-value-expressions</span> must have the same number
|
||
|
of value expressions. The data types of the corresponding expressions of the <span class="italic">row-value-expressions</span> must be compatible. The value of
|
||
|
each expression on the left side is compared with the value of its corresponding
|
||
|
expression on the right side.</p>
|
||
|
<p>When a <span class="italic">row-value-expression</span> is specified
|
||
|
and a <span class="italic">fullselect</span> is also specified:</p>
|
||
|
<ul>
|
||
|
<li>SELECT * is not allowed in the outermost select lists of the <span class="italic">fullselect</span>.</li>
|
||
|
<li>The result table of the <span class="italic">fullselect</span> must have the
|
||
|
same number of columns as the <span class="italic">row-value-expression</span>.
|
||
|
The data types of the corresponding expressions of the <span class="italic">row-value-expression</span> and the <span class="italic">fullselect</span> must
|
||
|
be compatible. The value of each expression on the left side is compared with
|
||
|
the value of its corresponding expression on the right side.</li></ul>
|
||
|
<p>The result of the predicate depends on the operator:</p>
|
||
|
<ul>
|
||
|
<li>If the operator is =, the result of the predicate is:
|
||
|
<ul>
|
||
|
<li>True if all pairs of corresponding value expressions evaluate to true.</li>
|
||
|
<li>False if any one pair of corresponding value expressions evaluates to
|
||
|
false.</li>
|
||
|
<li>Otherwise, unknown (that is, if at least one comparison of corresponding
|
||
|
value expressions is unknown because of a null value and no pair of corresponding
|
||
|
value expressions evaluates to false).</li></ul></li>
|
||
|
<li>If the operator is <>, the result of the predicate is:
|
||
|
<ul>
|
||
|
<li>True if any one pair of corresponding value expressions evaluates to true.</li>
|
||
|
<li>False if all pairs of corresponding value expressions evaluate to false.</li>
|
||
|
<li>Otherwise, unknown (that is, if at least one comparison of corresponding
|
||
|
value expressions is unknown because of a null value and no pair of corresponding
|
||
|
value expressions evaluates to true).</li></ul></li></ul>
|
||
|
<p>If the corresponding operands of the predicate are SBCS data, mixed data,
|
||
|
or Unicode data, and if the sort sequence in effect at the time the statement
|
||
|
is executed is not *HEX, then the comparison of the operands is performed
|
||
|
using weighted values for the operands. The weighted values are based on the
|
||
|
sort sequence.</p>
|
||
|
<p>For values <var class="pv">x</var> and <var class="pv">y</var>: </p>
|
||
|
<dl>
|
||
|
<dt class="bold">Predicate</dt>
|
||
|
<dd class="bold">Is true if and only if...</dd>
|
||
|
<dt class="bold"><tt class="xph"><var class="pv">x</var> = <var class="pv">y</var></tt></dt>
|
||
|
<dd><var class="pv">x</var> is equal to <var class="pv">y</var>
|
||
|
</dd>
|
||
|
<dt class="bold"><tt class="xph"><var class="pv">x</var><> <var class="pv">y</var></tt></dt>
|
||
|
<dd><var class="pv">x</var> is not equal to <var class="pv">y</var>
|
||
|
</dd>
|
||
|
<dt class="bold"><tt class="xph"><var class="pv">x</var> < <var class="pv">y</var></tt></dt>
|
||
|
<dd><var class="pv">x</var> is less than <var class="pv">y</var>
|
||
|
</dd>
|
||
|
<dt class="bold"><tt class="xph"><var class="pv">x</var> > <var class="pv">y</var></tt></dt>
|
||
|
<dd><var class="pv">x</var> is greater than <var class="pv">y</var>
|
||
|
</dd>
|
||
|
<dt class="bold"><tt class="xph"><var class="pv">x</var>>= <var class="pv">y</var></tt></dt>
|
||
|
<dd><var class="pv">x</var> is greater than or equal to <var class="pv">y</var>
|
||
|
</dd>
|
||
|
<dt class="bold"><tt class="xph"><var class="pv">x</var><= <var class="pv">y</var></tt></dt>
|
||
|
<dd><var class="pv">x</var> is less than or equal to <var class="pv">y</var>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq391"></a>
|
||
|
<h4 id="wq391">Examples</h4>
|
||
|
<p><span class="italic">Example 1</span></p>
|
||
|
<pre class="xmp"> EMPNO = '528671'
|
||
|
|
||
|
PRTSTAFF <> :VAR1
|
||
|
|
||
|
SALARY + BONUS + COMM < 20000
|
||
|
|
||
|
SALARY > <span class="bold">(SELECT AVG(</span>SALARY<span class="bold">)
|
||
|
FROM</span> EMPLOYEE<span class="bold">)</span></pre>
|
||
|
<p><span class="italic">Example 2</span>: List the name, first name,
|
||
|
and salary of the employee who is responsible for the 'OP1000' project.</p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> LASTNAME, FIRSTNME, SALARY
|
||
|
<span class="bold">FROM</span> EMPLOYEE X
|
||
|
<span class="bold">WHERE</span> EMPNO = <span class="bold">( SELECT </span> RESPEMP
|
||
|
<span class="bold">FROM</span> PROJA1 Y
|
||
|
<span class="bold">WHERE</span> MAJPROJ = 'OP1000' <span class="bold">)</span></pre>
|
||
|
<a name="wq392"></a>
|
||
|
<h3 id="wq392"><a href="rbafzmst02.htm#ToC_291">Quantified predicate</a></h3><a id="idx756" name="idx756"></a><a id="idx757" name="idx757"></a><a id="idx758" name="idx758"></a><a id="idx759" name="idx759"></a><a id="idx760" name="idx760"></a>
|
||
|
<a href="rbafzmstch2pred.htm#synqualified"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
||
|
<a name="wq393"></a>
|
||
|
<div class="fignone" id="wq393">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn30.htm"
|
||
|
border="0" /></span><a href="#skipsyn-29"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a> (1)
|
||
|
>>-+-<span class="italic">expression</span>--+- = --+-------+-SOME-+--(--<span class="italic">fullselect</span>--)-------+-><
|
||
|
| +- <> -+ +-ANY--+ |
|
||
|
| +- < --+ '-ALL--' |
|
||
|
| +- > --+ |
|
||
|
| +- <= -+ |
|
||
|
| '- >= -' |
|
||
|
+-(--<span class="italic">row-value-expression</span>--)-- = --+-SOME-+--(--<span class="italic">fullselect</span>--)-+
|
||
|
| '-ANY--' |
|
||
|
'-(--<span class="italic">row-value-expression</span>--)-- <> --ALL--(--<span class="italic">fullselect</span>--)-----'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-29" id="skipsyn-29"></a>
|
||
|
<a name="wq394"></a>
|
||
|
<div class="notelisttitle" id="wq394">Notes:</div>
|
||
|
<ol type="1">
|
||
|
<li>Other comparison operators are also supported. </li>
|
||
|
</ol></div>
|
||
|
<a name="synqualified"></a>
|
||
|
<p id="synqualified">A <span class="italic">quantified predicate</span> compares a value or values with a set of values.</p>
|
||
|
<p>When <span class="italic">expression</span> is specified, the fullselect
|
||
|
must return a single result column. The fullselect can return any number of
|
||
|
values, whether null or not null. The result depends on the operator that
|
||
|
is specified:</p>
|
||
|
<ul>
|
||
|
<li>When ALL is specified, the result of the predicate is:
|
||
|
<ul>
|
||
|
<li>True if the result of the fullselect is empty, or if the specified
|
||
|
relationship is true for every value returned by the fullselect.</li>
|
||
|
<li>False if the specified relationship is false for at least one
|
||
|
value returned by the fullselect.</li>
|
||
|
<li>Unknown if the specified relationship is not false for any
|
||
|
values returned by the fullselect and at least one comparison is unknown because
|
||
|
of a null value.</li></ul></li>
|
||
|
<li>When SOME or ANY is specified, the result of the predicate is:
|
||
|
<ul>
|
||
|
<li>True if the specified relationship is true for at least one
|
||
|
value returned by the fullselect.</li>
|
||
|
<li>False if the result of the fullselect is empty, or if the specified
|
||
|
relationship is false for every value returned by the fullselect.</li>
|
||
|
<li>Unknown if the specified relationship is not true for any of
|
||
|
the values returned by the fullselect and at least one comparison is unknown
|
||
|
because of a null value.</li></ul></li></ul>
|
||
|
<p>When <span class="italic">row-value-expression</span> is specified,
|
||
|
the number of result columns returned by the fullselect must be the same as
|
||
|
the number of value expressions specified by <span class="italic">row-value-expression</span>. The fullselect can return any number of rows of values. The data types
|
||
|
of the corresponding expressions of the row value expressions must be compatible.
|
||
|
The value of each expression from <span class="italic">row-value-expression</span> is compared with the value of the corresponding result column from the
|
||
|
fullselect. SELECT * is not allowed in the outermost select lists of the <span class="italic">fullselect</span>.</p>
|
||
|
<p>The value of the predicate depends on the operator that is specified:</p>
|
||
|
<ul>
|
||
|
<li>When ALL is specified, the result of the predicate is:
|
||
|
<ul>
|
||
|
<li>True if the result of the fullselect is empty or if the specified
|
||
|
relationship is true for every row returned by fullselect.</li>
|
||
|
<li>False if the specified relationship is false for at least one
|
||
|
row returned by the fullselect.</li>
|
||
|
<li>Unknown if the specified relationship is not false for any
|
||
|
row returned by the fullselect and at least one comparison is unknown because
|
||
|
of a null value.</li></ul></li>
|
||
|
<li>When SOME or ANY is specified, the result of the predicate is:
|
||
|
<ul>
|
||
|
<li>True if the specified relationship is true for at least one
|
||
|
row returned by the fullselect.</li>
|
||
|
<li>False if the result of the fullselect is empty or if the specified
|
||
|
relationship is false for every row returned by the fullselect.</li>
|
||
|
<li>Unknown if the specified relationship is not true for any of
|
||
|
the rows returned by the fullselect and at least one comparison is unknown
|
||
|
because of a null value.</li></ul></li></ul>
|
||
|
<p>If the corresponding operands of the predicate are SBCS data, mixed data,
|
||
|
or Unicode data, and if the sort sequence in effect at the time the statement
|
||
|
is executed is not *HEX, then the comparison of the operands is performed
|
||
|
using weighted values for the operands. The weighted values are based on the
|
||
|
sort sequence.</p>
|
||
|
<a name="wq396"></a>
|
||
|
<h4 id="wq396">Examples</h4>
|
||
|
<p> </p>
|
||
|
<p>Table <span class="bold">TBLA</span> </p>
|
||
|
<pre class="xmp">COLA
|
||
|
-----
|
||
|
1
|
||
|
2
|
||
|
3
|
||
|
4
|
||
|
null</pre><p class="indatacontent"> Table <span class="bold">TBLB</span> </p>
|
||
|
<pre class="xmp">COLB
|
||
|
-----
|
||
|
2
|
||
|
3</pre>
|
||
|
<p><span class="italic">Example 1</span> </p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> * <span class="bold">FROM</span> TBLA <span class="bold">WHERE</span> COLA = <span class="bold">ANY(SELECT</span> COLB <span class="bold">FROM</span> TBLB<span class="bold">)</span></pre>
|
||
|
<p>Results in 2,3. The subselect returns (2,3). COLA in rows 2 and 3 equals
|
||
|
at least one of these values.</p>
|
||
|
<p><span class="italic">Example 2</span> </p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> * <span class="bold">FROM</span> TBLA <span class="bold">WHERE</span> COLA > <span class="bold">ANY(SELECT</span> COLB <span class="bold">FROM</span> TBLB<span class="bold">)</span></pre>
|
||
|
<p>Results in 3,4. The subselect returns (2,3). COLA in rows 3 and 4 is greater
|
||
|
than at least one of these values.</p>
|
||
|
<p><span class="italic">Example 3</span> </p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> * <span class="bold">FROM</span> TBLA <span class="bold">WHERE</span> COLA > <span class="bold">ALL(SELECT</span> COLB <span class="bold">FROM</span> TBLB<span class="bold">)</span></pre>
|
||
|
<p>Results in 4. The subselect returns (2,3). COLA in row 4 is the only one
|
||
|
that is greater than both these values.</p>
|
||
|
<p><span class="italic">Example 4</span> </p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> * <span class="bold">FROM</span> TBLA <span class="bold">WHERE</span> COLA > <span class="bold">ALL(SELECT</span> COLB <span class="bold">FROM</span> TBLB<span class="bold"> WHERE</span> COLB<0<span class="bold">)</span></pre>
|
||
|
<p>Results in 1,2,3,4, and null. The subselect returns no values. Thus, the
|
||
|
predicate is true for all rows in TBLA.</p>
|
||
|
<p><span class="italic">Example 5</span> </p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> * <span class="bold">FROM</span> TBLA <span class="bold">WHERE</span> COLA > <span class="bold">ANY(SELECT</span> COLB <span class="bold">FROM</span> TBLB<span class="bold"> WHERE</span> COLB<0<span class="bold">)</span></pre>
|
||
|
<p>Results in the empty set. The subselect returns no values. Thus, the predicate
|
||
|
is false for all rows in TBLA.</p>
|
||
|
<a name="wq397"></a>
|
||
|
<h3 id="wq397"><a href="rbafzmst02.htm#ToC_293">BETWEEN predicate</a></h3><a id="idx761" name="idx761"></a><a id="idx762" name="idx762"></a>
|
||
|
<a href="rbafzmstch2pred.htm#synbetween"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
||
|
<a name="wq398"></a>
|
||
|
<div class="fignone" id="wq398">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn31.htm"
|
||
|
border="0" /></span><a href="#skipsyn-30"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>>>-<span class="italic">expression</span>--+-----+--BETWEEN--<span class="italic">expression</span>--AND--<span class="italic">expression</span>---><
|
||
|
'-NOT-'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-30" id="skipsyn-30"></a></div>
|
||
|
<a name="synbetween"></a>
|
||
|
<p id="synbetween">The BETWEEN predicate compares a value with a range of
|
||
|
values.</p>
|
||
|
<p>If the operands of the predicate are SBCS data, mixed data, or Unicode
|
||
|
data, and if the sort sequence in effect at the time the statement is executed
|
||
|
is not *HEX, then the comparison of the operands is performed using weighted
|
||
|
values for the operands. The weighted values are based on the sort sequence.</p>
|
||
|
<p>The BETWEEN predicate: </p>
|
||
|
<pre class="xmp"> value1 <span class="bold">BETWEEN</span> value2 <span class="bold">AND</span> value3</pre><p class="indatacontent"> is logically equivalent to the search condition: </p>
|
||
|
<pre class="xmp"> value1 >= value2 <span class="bold">AND</span> value1 <= value3</pre>
|
||
|
<p>The BETWEEN predicate: </p>
|
||
|
<pre class="xmp"> value1 <span class="bold">NOT BETWEEN</span> value2 <span class="bold">AND</span> value3</pre><p class="indatacontent"> is equivalent to the search condition: </p>
|
||
|
<pre class="xmp"> <span class="bold">NOT</span>(value1 <span class="bold">BETWEEN</span> value2 <span class="bold">AND</span> value3);that is,
|
||
|
value1 < value2 <span class="bold">OR</span> value1 > value3.</pre>
|
||
|
<p>If the operands of the BETWEEN predicate are strings with different CCSIDs,
|
||
|
operands are converted as if the above logically-equivalent search conditions
|
||
|
were specified.</p>
|
||
|
<p>Given a mixture of datetime values and string representations of datetime
|
||
|
values, all values are converted to the data type of the datetime operand.</p>
|
||
|
<a name="wq399"></a>
|
||
|
<h4 id="wq399">Examples</h4>
|
||
|
<pre class="xmp"><span> <tt class="xph">EMPLOYEE.SALARY <span class="bold">BETWEEN</span> 20000 <span class="bold">AND</span> 40000</tt></span>
|
||
|
|
||
|
<span> <tt class="xph">SALARY <span class="bold">NOT BETWEEN</span> 20000 + :HV1 <span class="bold">AND</span> 40000</tt></span></pre>
|
||
|
<a name="wq400"></a>
|
||
|
<h3 id="wq400"><a href="rbafzmst02.htm#ToC_295">DISTINCT predicate</a></h3><a id="idx763" name="idx763"></a><a id="idx764" name="idx764"></a>
|
||
|
<a href="rbafzmstch2pred.htm#syndistinct"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
||
|
<a name="wq401"></a>
|
||
|
<div class="fignone" id="wq401">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn32.htm"
|
||
|
border="0" /></span><a href="#skipsyn-31"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>>>---<span class="italic">expression</span>--IS--+-----+--DISTINCT FROM--<span class="italic">expression</span>--------><
|
||
|
'-NOT-'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-31" id="skipsyn-31"></a></div>
|
||
|
<a name="syndistinct"></a>
|
||
|
<p id="syndistinct">The DISTINCT predicate compares a value with another value.</p>
|
||
|
<p>When the predicate is IS DISTINCT, the result of the predicate
|
||
|
is true if the comparison of the expressions evaluates to true. Otherwise,
|
||
|
the result of the predicate is false. The result cannot be unknown.</p>
|
||
|
<p>When the predicate IS NOT DISTINCT FROM, the result of the predicate
|
||
|
is true if the comparison of the expressions evaluates to true (null values
|
||
|
are considered equal to null values). Otherwise, the predicate is false. The
|
||
|
result cannot be unknown.</p>
|
||
|
<p>The DISTINCT predicate: </p>
|
||
|
<pre class="xmp"> value1 <span class="bold">IS NOT DISTINCT FROM</span> value2 </pre><p class="indatacontent"> is logically equivalent to the search condition: </p>
|
||
|
<pre class="xmp"> <span class="bold">(</span> value1 <span class="bold">IS NOT NULL AND</span> value2 <span class="bold">IS NOT NULL AND</span> value1 = value2 <span class="bold">)</span>
|
||
|
<span class="bold">OR</span>
|
||
|
<span class="bold">(</span> value1 <span class="bold">IS NULL AND</span> value2 <span class="bold">IS NULL )</span>
|
||
|
</pre>
|
||
|
<p>The DISTINCT predicate: </p>
|
||
|
<pre class="xmp"> value1 <span class="bold">IS DISTINCT FROM</span> value2 </pre><p class="indatacontent"> is logically equivalent to the search condition: </p>
|
||
|
<pre class="xmp"><span class="bold">NOT</span> (value1 <span class="bold">IS NOT DISTINCT FROM </span> value2) </pre>
|
||
|
<p>If the operands of the DISTINCT predicate are strings with different CCSIDs,
|
||
|
operands are converted as if the above logically-equivalent search conditions
|
||
|
were specified.</p>
|
||
|
<a name="wq402"></a>
|
||
|
<h4 id="wq402">Example</h4>
|
||
|
<p>Assume that table T1 exists and it has a single column C1, and three rows
|
||
|
with the following values for C1: 1, 2, null. The following query produces
|
||
|
the following results:</p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> * <span class="bold">FROM</span> T1
|
||
|
<span class="bold">WHERE</span> C1 <span class="bold">IS DISTINCT FROM</span> :HV</pre>
|
||
|
<p></p>
|
||
|
<a name="wq403"></a>
|
||
|
<table id="wq403" width="100%" summary="" border="1" frame="border" rules="all">
|
||
|
<thead valign="bottom">
|
||
|
<tr valign="bottom">
|
||
|
<th id="wq404" align="left">C1</th>
|
||
|
<th id="wq405" align="left">:HV</th>
|
||
|
<th id="wq406" align="left">Result</th>
|
||
|
</tr>
|
||
|
</thead>
|
||
|
<tbody valign="top">
|
||
|
<tr>
|
||
|
<td headers="wq404">1</td>
|
||
|
<td headers="wq405">2</td>
|
||
|
<td headers="wq406">True</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq404">2</td>
|
||
|
<td headers="wq405">2</td>
|
||
|
<td headers="wq406">False</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq404">1</td>
|
||
|
<td headers="wq405">Null</td>
|
||
|
<td headers="wq406">True</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq404">Null</td>
|
||
|
<td headers="wq405">Null</td>
|
||
|
<td headers="wq406">False</td>
|
||
|
</tr>
|
||
|
</tbody>
|
||
|
</table>
|
||
|
<p>The following query produces the following results:</p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> * <span class="bold">FROM</span> T1
|
||
|
<span class="bold">WHERE</span> C1 <span class="bold">IS NOT DISTINCT FROM</span> :HV</pre>
|
||
|
<p></p>
|
||
|
<a name="wq407"></a>
|
||
|
<table id="wq407" width="100%" summary="" border="1" frame="border" rules="all">
|
||
|
<thead valign="bottom">
|
||
|
<tr valign="bottom">
|
||
|
<th id="wq408" align="left">C1</th>
|
||
|
<th id="wq409" align="left">:HV</th>
|
||
|
<th id="wq410" align="left">Result</th>
|
||
|
</tr>
|
||
|
</thead>
|
||
|
<tbody valign="top">
|
||
|
<tr>
|
||
|
<td headers="wq408">1</td>
|
||
|
<td headers="wq409">2</td>
|
||
|
<td headers="wq410">False</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq408">2</td>
|
||
|
<td headers="wq409">2</td>
|
||
|
<td headers="wq410">True</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq408">1</td>
|
||
|
<td headers="wq409">Null</td>
|
||
|
<td headers="wq410">False</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq408">Null</td>
|
||
|
<td headers="wq409">Null</td>
|
||
|
<td headers="wq410">True</td>
|
||
|
</tr>
|
||
|
</tbody>
|
||
|
</table>
|
||
|
<a name="wq411"></a>
|
||
|
<h3 id="wq411"><a href="rbafzmst02.htm#ToC_297">EXISTS predicate</a></h3><a id="idx765" name="idx765"></a><a id="idx766" name="idx766"></a>
|
||
|
<a href="rbafzmstch2pred.htm#synexists"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
||
|
<a name="wq412"></a>
|
||
|
<div class="fignone" id="wq412">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn33.htm"
|
||
|
border="0" /></span><a href="#skipsyn-32"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>>>-EXISTS--<span><span class="italic">( fullselect )</span></span>--------------------------------------><
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-32" id="skipsyn-32"></a></div>
|
||
|
<a name="synexists"></a>
|
||
|
<p id="synexists">The EXISTS predicate tests for the existence
|
||
|
of certain rows. The fullselect may specify any number of columns, and </p>
|
||
|
<ul>
|
||
|
<li>The result is true only if the number of rows specified by
|
||
|
the fullselect is not zero.</li>
|
||
|
<li>The result is false only if the number of rows specified by
|
||
|
the fullselect is zero.</li>
|
||
|
<li>The result cannot be unknown.</li></ul>
|
||
|
<p>The values returned by the fullselect are ignored.</p>
|
||
|
<a name="wq413"></a>
|
||
|
<h4 id="wq413">Example</h4>
|
||
|
<pre class="xmp"> <span class="bold">EXISTS (SELECT</span> *
|
||
|
<span class="bold">FROM</span> EMPLOYEE <span class="bold">WHERE</span> SALARY <span class="bold">></span> 60000<span class="bold">)</span></pre>
|
||
|
<a name="wq414"></a>
|
||
|
<h3 id="wq414"><a href="rbafzmst02.htm#ToC_299">IN predicate</a></h3><a id="idx767" name="idx767"></a><a id="idx768" name="idx768"></a>
|
||
|
<a href="rbafzmstch2pred.htm#synin"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
||
|
<a name="wq415"></a>
|
||
|
<div class="fignone" id="wq415">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn34.htm"
|
||
|
border="0" /></span><a href="#skipsyn-33"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>>>-+-<span class="italic">expression</span>--+-----+--IN--+-<span>(</span>--<span><span class="italic">fullselect</span></span>--<span>)</span>---------+-----+-><
|
||
|
| '-NOT-' | .-,--------------. | |
|
||
|
| | V | | |
|
||
|
| +-(------<span class="italic">expression</span>---+--)-+ |
|
||
|
| '---<span class="italic">expression</span>-------------' |
|
||
|
'-<span>(</span>--<span><span class="italic">row-value-expression</span></span>--<span>)</span>--+-----+--<span>IN</span>--<span>(</span>--<span><span class="italic">fullselect</span></span>--<span>)</span>-'
|
||
|
'-<span>NOT</span>-'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-33" id="skipsyn-33"></a></div>
|
||
|
<a name="synin"></a>
|
||
|
<p id="synin">The IN predicate compares a value or values with
|
||
|
a set of values.</p>
|
||
|
<p>When a single <span class="italic">expression</span> is specified
|
||
|
on the left side of the operator, the IN predicate compares a value with a
|
||
|
set of values. When a fullselect is specified, the fullselect must return
|
||
|
a single result column, and can return any number of values, whether null
|
||
|
or not null. The data type of <span class="italic">expression</span> and the data
|
||
|
type of the result column of the fullselect or the <span class="italic">expression</span> on the right side of the operator must be compatible. Each variable
|
||
|
must identify a structure or variable that is described in accordance with
|
||
|
the rule for declaring host structures or variables.</p>
|
||
|
<p>When a <span class="italic">row-value-expression</span> is specified,
|
||
|
the IN predicate compares values with a collection of values. </p>
|
||
|
<ul>
|
||
|
<li>SELECT * is not allowed in the outermost select lists of the <span class="italic">fullselect</span>.</li>
|
||
|
<li>The result table of the <span class="italic">fullselect</span> must have the
|
||
|
same number of columns as the <span class="italic">row-value-expression</span>.
|
||
|
The data types of the corresponding expressions of the <span class="italic">row-value-expression</span> and the <span class="italic">fullselect</span> must
|
||
|
be compatible. The value of each expression on the left side is compared with
|
||
|
the value of its corresponding expression on the right side.</li></ul>
|
||
|
<p>The value of the predicate depends on the operator that is specified:</p>
|
||
|
<ul>
|
||
|
<li>When the operator is IN, the result of the predicate is:
|
||
|
<ul>
|
||
|
<li>True if at least one row returned from the fullselect is equal to the <span class="italic">row-value-expression</span>.</li>
|
||
|
<li>False if the result of the fullselect is empty or if no row returned from
|
||
|
the fullselect is equal to the <span class="italic">row-value-expression</span>.</li>
|
||
|
<li>Otherwise, unknown (that is, if the comparison of <span class="italic">row-value-expression</span> to the row returned from the fullselect evaluates
|
||
|
to unknown because of a null value for at least one row returned from the
|
||
|
fullselect and no row returned from the fullselect is equal to the <span class="italic">row-value-expression</span>).</li></ul></li>
|
||
|
<li>When the operator is NOT IN, the result of the predicate is:
|
||
|
<ul>
|
||
|
<li>True if the result of the fullselect is empty or if the <span class="italic">row-value-expression</span> is not equal to any of the rows returned by the
|
||
|
fullselect.</li>
|
||
|
<li>False if the <span class="italic">row-value-expression</span> is equal to
|
||
|
at least one row returned by the fullselect.</li>
|
||
|
<li>Otherwise, unknown (that is, if the comparison of <span class="italic">row-value-expression</span> to the row returned from the fullselect evaluates
|
||
|
to unknown because of a null value for at least one row returned from the
|
||
|
fullselect and the comparison of <span class="italic">row-value-expression</span> to
|
||
|
the row returned from the fullselect is not true for any row returned by the
|
||
|
fullselect).</li></ul></li></ul>
|
||
|
<p>If the corresponding operands of the predicate are SBCS data, mixed data,
|
||
|
or Unicode data, and if the sort sequence in effect at the time the statement
|
||
|
is executed is not *HEX, then the comparison of the operands is performed
|
||
|
using weighted values for the operands. The weighted values are based on the
|
||
|
sort sequence.</p>
|
||
|
<p>An IN predicate is equivalent to other predicates as follows:</p>
|
||
|
<a name="wq416"></a>
|
||
|
<table id="wq416" width="100%" summary="" border="0" frame="void" rules="all">
|
||
|
<thead valign="bottom">
|
||
|
<tr valign="bottom">
|
||
|
<th id="wq417" align="left">IN predicate</th>
|
||
|
<th id="wq418" align="left">Equivalent predicate</th>
|
||
|
</tr>
|
||
|
</thead>
|
||
|
<tbody valign="top">
|
||
|
<tr>
|
||
|
<td headers="wq417">expression <span class="bold">IN</span> <span class="bold">(</span>expression<span class="bold">)</span></td>
|
||
|
<td headers="wq418">expression <span class="bold">=</span> expression</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq417">expression <span class="bold">IN (</span>fullselect<span class="bold">)</span></td>
|
||
|
<td headers="wq418">expression <span class="bold">= ANY (</span>fullselect<span class="bold">)</span></td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq417">expression <span class="bold">NOT IN (</span>fullselect<span class="bold">)</span></td>
|
||
|
<td headers="wq418">expression <span class="bold"><> ALL (</span>fullselect<span class="bold">)</span></td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq417">expression <span class="bold">IN (</span>value1, value2,
|
||
|
..., valuen<span class="bold">)</span></td>
|
||
|
<td headers="wq418">expression <span class="bold">IN (SELECT</span> * <span class="bold">FROM</span> R<span class="bold">)</span>
|
||
|
<p></p>Where T is a table with a single
|
||
|
row and R is a temporary table formed by the following fullselect:
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> value1 <span class="bold">FROM</span> T
|
||
|
<span class="bold">UNION</span>
|
||
|
<span class="bold">SELECT</span> value2 <span class="bold">FROM</span> T
|
||
|
<span class="bold">UNION</span>
|
||
|
.
|
||
|
.
|
||
|
.
|
||
|
<span class="bold">UNION</span>
|
||
|
<span class="bold">SELECT</span> valuen <span class="bold">FROM</span> T</pre></td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq417">row-value-expression <span class="bold">IN (</span>fullselect<span class="bold">)</span></td>
|
||
|
<td headers="wq418">row-value-expression <span class="bold">= SOME (</span> fullselect<span class="bold">)</span></td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq417">row-value-expression <span class="bold">IN (</span>fullselect<span class="bold">)</span></td>
|
||
|
<td headers="wq418">row-value-expression <span class="bold">= ANY (</span> fullselect<span class="bold">)</span></td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq417">row-value-expression <span class="bold">NOT IN (</span>fullselect<span class="bold">)</span></td>
|
||
|
<td headers="wq418">row-value-expression <span class="bold"><> ALL (</span> fullselect<span class="bold">)</span></td>
|
||
|
</tr>
|
||
|
</tbody>
|
||
|
</table>
|
||
|
<p>If the operands of the IN predicate have different data types or attributes,
|
||
|
the rules used to determine the data type for evaluation of the IN predicate
|
||
|
are those for UNION, UNION ALL, EXCEPT, and INTERSECT. For a description,
|
||
|
see <a href="rbafzmstopcomb.htm#opcomb">Rules for result data types</a>.</p>
|
||
|
<p>If the operands of the IN predicate are strings with different CCSIDs,
|
||
|
the rules used to determine which operands are converted are those for operations
|
||
|
that combine strings. For a description, see <a href="rbafzmstuuall.htm#uuall">Conversion rules for operations that combine strings</a>.</p>
|
||
|
<a name="wq419"></a>
|
||
|
<h4 id="wq419">Examples</h4>
|
||
|
<p></p>
|
||
|
<pre class="xmp"> DEPTNO <span class="bold">IN (</span>'D01', 'B01', 'C01'<span class="bold">)</span>
|
||
|
|
||
|
EMPNO <span class="bold">IN(SELECT</span> EMPNO <span class="bold">FROM</span> EMPLOYEE <span class="bold">WHERE</span> WORKDEPT = 'E11'<span class="bold">)</span></pre>
|
||
|
<a name="ch2like"></a>
|
||
|
<h3 id="ch2like"><a href="rbafzmst02.htm#ToC_301">LIKE predicate</a></h3><a id="idx769" name="idx769"></a><a id="idx770" name="idx770"></a>
|
||
|
<a href="rbafzmstch2pred.htm#synlike"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
||
|
<a name="wq420"></a>
|
||
|
<div class="fignone" id="wq420">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn35.htm"
|
||
|
border="0" /></span><a href="#skipsyn-34"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>>>-<span class="italic">match-expression</span>--+-----+--LIKE--<span class="italic">pattern-expression</span>--+---------------------------+-><
|
||
|
'-NOT-' '-ESCAPE--<span class="italic">escape-expression</span>-'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-34" id="skipsyn-34"></a></div>
|
||
|
<a name="synlike"></a>
|
||
|
<p id="synlike">The LIKE predicate searches for strings that have a certain
|
||
|
pattern. The pattern is specified by a string in which the underscore and
|
||
|
percent sign have special meanings. Trailing blanks in a pattern are a part
|
||
|
of the pattern.</p>
|
||
|
<p>If the value of any of the arguments is null, the result of the LIKE predicate
|
||
|
is unknown.</p>
|
||
|
<p>The <span class="italic">match-expression</span>, <span class="italic">pattern-expression</span>, and <span class="italic">escape-expression</span> must identify strings
|
||
|
or numbers. A numeric argument is cast to a character string before evaluating
|
||
|
the predicate. For more information on converting numeric to a character string,
|
||
|
see <a href="rbafzmstscale.htm#scavarchar">VARCHAR</a>. The values for <span class="italic">match-expression</span>, <span class="italic">pattern-expression</span>, and <span class="italic">escape-expression</span> must either all be binary strings or none can be binary
|
||
|
strings. The three arguments can include a mixture of character strings and
|
||
|
graphic strings.</p>
|
||
|
<p>None of the expressions can yield a distinct type. However, it can be a
|
||
|
function that casts a distinct type to its source type.</p>
|
||
|
<p>If the operands of the predicate are SBCS data, mixed data, or Unicode
|
||
|
data, and if the sort sequence in effect at the time the statement is executed
|
||
|
is not *HEX, then the comparison of the operands is performed using weighted
|
||
|
values for the operands. The weighted values are based on the sort sequence.
|
||
|
An ICU sort sequence is not allowed with a LIKE predicate.</p>
|
||
|
<p>With character strings, the terms <span class="italic">character</span>, <span class="italic">percent sign</span>, and <span class="italic">underscore</span> in
|
||
|
the following discussion refer to single-byte characters. With graphic strings,
|
||
|
the terms refer to double-byte or Unicode characters. With binary strings,
|
||
|
the terms refer to the code points of those single-byte characters.</p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><span class="italic">match-expression</span></dt>
|
||
|
<dd>An expression that specifies the string that is to be examined to see
|
||
|
if it conforms to a certain pattern of characters.
|
||
|
</dd>
|
||
|
<dt class="bold">LIKE <span class="italic">pattern-expression</span></dt>
|
||
|
<dd>An expression that specifies the string that is to be matched.
|
||
|
<p><span class="bold">Simple description</span>: A simple description of the LIKE pattern
|
||
|
is as follows: </p>
|
||
|
<ul>
|
||
|
<li>The underscore sign (_) represents any single character. <a id="idx771" name="idx771"></a></li>
|
||
|
<li>The percent sign (%) represents a string of zero or more <a id="idx772" name="idx772"></a>characters.</li>
|
||
|
<li>Any other character represents itself.</li></ul>
|
||
|
<p>If the <span class="italic">pattern-expression</span> needs to include
|
||
|
either the underscore or the percent character, the <span class="italic">escape-expression</span> is used to specify a character to precede either the underscore or percent
|
||
|
character in the pattern.</p>
|
||
|
<p><span class="bold">Rigorous description</span>:
|
||
|
Let <var class="pv">x</var> denote a value of <var class="pv">match-expression</var> and <var class="pv">y</var> denote
|
||
|
the value of <var class="pv">pattern-expression</var>.</p>
|
||
|
<p>The string <var class="pv">y</var> is
|
||
|
interpreted as a sequence of the minimum number of substring specifiers so
|
||
|
each character of <var class="pv">y</var> is part of exactly one substring specifier. A
|
||
|
substring specifier is an underscore, a percent sign, or any nonempty sequence
|
||
|
of characters other than an underscore or a percent sign.</p>
|
||
|
<p>The result
|
||
|
of the predicate is unknown if <var class="pv">x</var> or <var class="pv">y</var> is the null value.
|
||
|
Otherwise, the result is either true or false. The result is true if <var class="pv">x</var> and <var class="pv">y</var> are both empty strings or if there exists a partitioning
|
||
|
of <var class="pv">x</var> into substrings such that: </p>
|
||
|
<ul>
|
||
|
<li>A substring of <var class="pv">x</var> is a sequence of zero or more contiguous characters
|
||
|
and each character of <var class="pv">x</var> is part of exactly one substring.</li>
|
||
|
<li>If the <var class="pv">n</var>th substring specifier is an underscore, the <var class="pv">n</var>th
|
||
|
substring of <var class="pv">x</var> is any single character.</li>
|
||
|
<li>If the <var class="pv">n</var>th substring specifier is a percent sign, the <var class="pv">n</var>th
|
||
|
substring of <var class="pv">x</var> is any sequence of zero or more characters.</li>
|
||
|
<li>If the <var class="pv">n</var>th substring specifier is neither an underscore nor a
|
||
|
percent sign, the <var class="pv">n</var>th substring of <var class="pv">x</var> is equal to that substring
|
||
|
specifier and has the same length as that substring specifier.</li>
|
||
|
<li>The number of substrings of <var class="pv">x</var> is the same as the number of substring
|
||
|
specifiers.</li></ul>
|
||
|
<p>It follows that if <var class="pv">y</var> is an empty string and <var class="pv">x</var> is
|
||
|
not an empty string, the result is false. Similarly, it follows that if <var class="pv">y</var> is an empty string and <var class="pv">x</var> is not an empty string consisting
|
||
|
of other than percent signs, the result is false.</p>
|
||
|
<p>The predicate <var class="pv">x</var><tt class="xph"> NOT LIKE </tt><var class="pv">y</var> is equivalent to the search condition <tt class="xph">NOT(<var class="pv">x</var> LIKE <var class="pv">y</var>)</tt>.</p>
|
||
|
<p>If necessary, the CCSID of the <span class="italic">match-expression</span>, <span class="italic">pattern-expression</span>, and <span class="italic">escape-expression</span> are converted to the
|
||
|
compatible CCSID between the <span class="italic">match-expression</span> and <span class="italic">pattern-expression</span>.</p>
|
||
|
<p><span class="bold">Mixed data</span>: If the column is mixed data, the pattern can include both SBCS and
|
||
|
DBCS characters. The special characters in the pattern are interpreted as
|
||
|
follows: </p>
|
||
|
<ul>
|
||
|
<li>An SBCS underscore refers to one SBCS character.</li>
|
||
|
<li>A DBCS underscore refers to one DBCS character.</li>
|
||
|
<li>A percent sign (either SBCS or DBCS) refers to any number of characters
|
||
|
of any type, either SBCS or DBCS.</li>
|
||
|
<li>Redundant shifts in <span class="italic">match-expression</span> and <span class="italic">pattern-expression</span> are ignored.<sup class="fn"><a id="wq421" name="wq421" href="rbafzmstch2pred.htm#wq422">39</a></sup></li></ul><a id="idx773" name="idx773"></a><a id="idx774" name="idx774"></a><a id="idx775" name="idx775"></a>
|
||
|
<p><span class="bold">Unicode
|
||
|
data</span>: For Unicode, the special characters in the pattern are interpreted
|
||
|
as follows: </p>
|
||
|
<ul>
|
||
|
<li>An SBCS or DBCS underscore refers to one character (a character can be
|
||
|
one or more bytes)</li>
|
||
|
<li>A percent sign (either SBCS or DBCS) refers to a string of zero or more
|
||
|
characters (a character can be one or more bytes).</li></ul><p class="indatacontent"> When the LIKE predicate is used with Unicode data, the Unicode percent
|
||
|
sign and underscore use the code points indicated in the following table: </p>
|
||
|
<a name="wq423"></a>
|
||
|
<table id="wq423" width="100%" summary="" border="1" frame="hsides" rules="all">
|
||
|
<caption>Table 26. </caption>
|
||
|
<thead valign="bottom">
|
||
|
<tr>
|
||
|
<th id="wq424" width="33%" align="left" valign="top">Character</th>
|
||
|
<th id="wq425" width="33%" align="left" valign="top">UTF-8</th>
|
||
|
<th id="wq426" width="33%" align="left" valign="top">UTF-16 or UCS-2</th>
|
||
|
</tr>
|
||
|
</thead>
|
||
|
<tbody valign="top">
|
||
|
<tr>
|
||
|
<td headers="wq424">Half-width %</td>
|
||
|
<td headers="wq425">X'25'</td>
|
||
|
<td headers="wq426">X'0025'</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq424">Full-width %</td>
|
||
|
<td headers="wq425">X'EFBC85'</td>
|
||
|
<td headers="wq426">X'FF05'</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq424">Half-width _</td>
|
||
|
<td headers="wq425">X'5F'</td>
|
||
|
<td headers="wq426">X'005F'</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq424">Full-width _</td>
|
||
|
<td headers="wq425">X'EFBCBF'</td>
|
||
|
<td headers="wq426">X'FF3F'</td>
|
||
|
</tr>
|
||
|
</tbody>
|
||
|
</table><p class="indatacontent"> The full-width or half-width % matches zero or more characters. The
|
||
|
full-width or half width _ character matches exactly one character. (For EBCDIC
|
||
|
data, a full-width _ character matches one DBCS character.)</p>
|
||
|
<a name="likepatfl"></a>
|
||
|
<p id="likepatfl"><span class="bold">Parameter marker</span>:</p>
|
||
|
<p>When the pattern specified in a
|
||
|
LIKE predicate is a parameter marker, and a fixed-length character variable
|
||
|
is used to replace the parameter marker; specify a value for the variable
|
||
|
that is the correct length. If a correct length is not specified, the select
|
||
|
will not return the intended results.</p>
|
||
|
<p>For example, if the variable is
|
||
|
defined as CHAR(10), and the value WYSE% is assigned to that variable, the
|
||
|
variable is padded with blanks on assignment. The pattern used is </p>
|
||
|
<pre class="xmp"> 'WYSE% '</pre>
|
||
|
<p>This pattern requests the database manager to search for all
|
||
|
values that start with WYSE and end with five blank spaces. If you intended
|
||
|
to search for only the values that start with 'WYSE' you should assign the
|
||
|
value 'WYSE%%%%%%' to the variable.</p>
|
||
|
</dd>
|
||
|
<dt class="bold">ESCAPE <span class="italic">escape-expression</span></dt><a id="idx776" name="idx776"></a>
|
||
|
<dd>An expression that specifies a character to be used to modify the special
|
||
|
meaning of the underscore (_) and percent (%) characters in the pattern-expression.
|
||
|
This allows the LIKE predicate to be used to match values that contain the
|
||
|
actual percent and underscore characters. The following rules apply the use
|
||
|
of the ESCAPE clause and the <span class="italic">escape-expression</span>:
|
||
|
<ul>
|
||
|
<li>The <span class="italic">escape-expression</span> must be a string of length
|
||
|
1.<sup class="fn"><a id="wq427" name="wq427" href="rbafzmstch2pred.htm#wq428">40</a></sup></li>
|
||
|
<li>The <span class="italic">pattern-expression</span> must not contain the escape
|
||
|
character except when followed by the escape character, percent, or underscore.
|
||
|
<p>For example, if '+' is the escape character, any occurrences of '+'
|
||
|
other than '++', '+_', or '+%' in the <span class="italic">pattern-expression</span> is an error.</p></li>
|
||
|
<li>The <span class="italic">escape-expression</span> can be a parameter marker.</li></ul>
|
||
|
<p>The following example shows the effect of successive occurrences of
|
||
|
the escape character, which in this case is the plus sign (+).</p>
|
||
|
<a name="wq429"></a>
|
||
|
<table id="wq429" width="100%" summary="" border="0" frame="void" rules="all">
|
||
|
<thead valign="bottom">
|
||
|
<tr valign="bottom">
|
||
|
<th id="wq430" width="37%" align="left">When the pattern string is...</th>
|
||
|
<th id="wq431" width="62%" align="left">The actual pattern is...</th>
|
||
|
</tr>
|
||
|
</thead>
|
||
|
<tbody valign="top">
|
||
|
<tr>
|
||
|
<td headers="wq430">+%</td>
|
||
|
<td headers="wq431">A percent sign</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq430">++%</td>
|
||
|
<td headers="wq431">A plus sign followed by zero or
|
||
|
more arbitrary characters</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td headers="wq430">+++%</td>
|
||
|
<td headers="wq431">A plus sign followed by a percent
|
||
|
sign</td>
|
||
|
</tr>
|
||
|
</tbody>
|
||
|
</table>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq432"></a>
|
||
|
<h4 id="wq432">Examples</h4>
|
||
|
<a name="wq433"></a>
|
||
|
<h5 id="wq433">Example 1</h5>
|
||
|
<p>Search for the string 'SYSTEMS' appearing anywhere within the PROJNAME
|
||
|
column in the PROJECT table. </p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> PROJNAME
|
||
|
<span class="bold">FROM</span> PROJECT
|
||
|
<span class="bold">WHERE</span> PROJECT.PROJNAME <span class="bold">LIKE</span> '%SYSTEMS%'</pre>
|
||
|
<a name="wq434"></a>
|
||
|
<h5 id="wq434">Example 2</h5>
|
||
|
<p>Search for a string with a first character of 'J' that is exactly
|
||
|
two characters long in the FIRSTNME column of the EMPLOYEE table. </p>
|
||
|
<pre class="xmp"><span class="bold">SELECT</span> FIRSTNME
|
||
|
<span class="bold">FROM</span> EMPLOYEE
|
||
|
<span class="bold">WHERE</span> EMPLOYEE.FIRSTNME <span class="bold">LIKE</span> 'J_'</pre>
|
||
|
<a name="wq435"></a>
|
||
|
<h5 id="wq435">Example 3</h5>
|
||
|
<p>In this example: </p>
|
||
|
<pre class="xmp"><span class="bold">SELECT *</span>
|
||
|
<span class="bold">FROM</span> TABLEY
|
||
|
<span class="bold">WHERE</span> C1 <span class="bold">LIKE</span> 'AAAA+%BBB%' <span class="bold">ESCAPE</span> '+'</pre><p class="indatacontent">'+' is the escape character and
|
||
|
indicates that the search is for a string that starts with 'AAAA%BBB'.
|
||
|
The '+%' is interpreted as a single occurrence of '%' in the
|
||
|
pattern.</p>
|
||
|
<a name="wq436"></a>
|
||
|
<h5 id="wq436">Example 4</h5>
|
||
|
<p>Assume that a distinct type named ZIP_TYPE with a source data type of CHAR(5)
|
||
|
exists and an ADDRZIP column with data type ZIP_TYPE exists in some table
|
||
|
TABLEY. The following statement selects the row if the zip code (ADDRZIP)
|
||
|
begins with '9555'.</p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT *</span>
|
||
|
<span class="bold">FROM</span> TABLEY
|
||
|
<span class="bold">WHERE CHAR(</span>ADDRZIP<span class="bold">) LIKE</span> '9555%'</pre>
|
||
|
<a name="wq437"></a>
|
||
|
<h5 id="wq437">Example 5</h5>
|
||
|
<p>The RESUME column in sample table EMP_RESUME is defined as a CLOB. If the
|
||
|
variable LASTNAME has a value of 'JONES', the following statement selects
|
||
|
the RESUME column when the string JONES appears anywhere in the column.</p>
|
||
|
<pre class="xmp"> <span class="bold">SELECT</span> RESUME
|
||
|
<span class="bold">FROM</span> EMP_RESUME
|
||
|
<span class="bold">WHERE</span> RESUME <span class="bold">LIKE</span> '%'||LASTNAME||'%'</pre>
|
||
|
<a name="wq438"></a>
|
||
|
<h5 id="wq438">Example 6</h5>
|
||
|
<p>In the following table of EBCDIC examples, assume COL1 is mixed data. The
|
||
|
table shows the results when the predicates in the first column are evaluated
|
||
|
using the COL1 values from the second column: </p>
|
||
|
<a name="wq439"></a>
|
||
|
<div class="fignone" id="wq439">
|
||
|
<div class="mmobj">
|
||
|
<img src="rv3f001.gif" alt="Results when the predicates in the first column are evaluated using the COL1 values from the second column. Where predicate 'aaa Shift-out ABC%C Shift-in' compared to 'aaa Shift-out ABCZC Shift-in' returns true. Where predicate 'aaa Shift-out ABC Shift-in % Shift-out C Shift-in' compared to 'aaa Shift-out ABC Shift-in drz Shift-out C Shift-in' returns true. Where predicate 'a% Shift-out C Shift-in' compared to 'a Shift-out C Shift-in', 'ax Shift-out C Shift-in', and 'ab Shift-out DE Shift-in fg Shift-out C Shift-in' all return true. Where 'a_Shift-out C Shift-in' compared to 'a% Shift-out C Shift-in' returns true and 'a Shift-out XC Shift-in' returns false. Where 'a Shift-out __C Shift-in' compared to 'a Shift-out XC Shift-in' returns true and 'ax Shift-out C Shift-in' returns false. Where ''Shift-out Shift-in' compared to an empty string returns true. Where 'ab Shift-out C Shift-in_' compared to 'ab Shift-out C Shift-in d' and 'ab Shift-out Shift-in Shift-out C Shift-in' return true." /></div></div>
|
||
|
<a name="wq440"></a>
|
||
|
<h3 id="wq440"><a href="rbafzmst02.htm#ToC_309">NULL predicate</a></h3><a id="idx777" name="idx777"></a><a id="idx778" name="idx778"></a>
|
||
|
<a href="rbafzmstch2pred.htm#synnull"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
||
|
<a name="wq441"></a>
|
||
|
<div class="fignone" id="wq441">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn36.htm"
|
||
|
border="0" /></span><a href="#skipsyn-35"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>>>-<span class="italic">expression</span>--IS--+-----+--NULL-------------------------------><
|
||
|
'-NOT-'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-35" id="skipsyn-35"></a></div>
|
||
|
<a name="synnull"></a>
|
||
|
<p id="synnull">The NULL predicate tests for null values.</p>
|
||
|
<p>The result of a NULL predicate cannot be unknown. If the value of the expression
|
||
|
is null, the result is true. If the value is not null, the result is false.</p>
|
||
|
<p>If NOT is specified, the result is reversed.</p>
|
||
|
<a name="wq442"></a>
|
||
|
<h4 id="wq442">Examples</h4>
|
||
|
<p></p>
|
||
|
<pre class="xmp"> EMPLOYEE.PHONE <span class="bold">IS NULL</span>
|
||
|
|
||
|
SALARY <span class="bold">IS NOT NULL</span></pre>
|
||
|
<hr /><div class="fnnum"><a id="wq422" name="wq422" href="rbafzmstch2pred.htm#wq421">39</a>.</div>
|
||
|
<div class="fntext">Redundant shifts are normally ignored.
|
||
|
To guarantee that they are ignored, however, specify the IGNORE_LIKE_REDUNDANT_SHIFTS
|
||
|
query attribute. See <a href="../rzajq/rzajqkickoff.htm">Database Performance and Query Optimization</a> for information on setting query attributes.</div><div class="fnnum"><a id="wq428" name="wq428" href="rbafzmstch2pred.htm#wq427">40</a>.</div>
|
||
|
<div class="fntext">If it is NUL-terminated, a C character string variable of length 2 can
|
||
|
be specified.</div>
|
||
|
<br />
|
||
|
<hr /><br />
|
||
|
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmstdatetimearith.htm">Previous Page</a> | <a href="rbafzmstch2srch.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>
|