716 lines
37 KiB
HTML
716 lines
37 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 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="Use recursive queries" />
|
||
<meta name="abstract" content="This topic introduces the use of recursive common table expressions and recursive views." />
|
||
<meta name="description" content="This topic introduces the use of recursive common table expressions and recursive views." />
|
||
<meta name="DC.subject" content="recursive view, recursive query, view, recursive" />
|
||
<meta name="keywords" content="recursive view, recursive query, view, recursive" />
|
||
<meta name="DC.Relation" scheme="URI" content="rbafytexas.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="rbafyrecursivequeries" />
|
||
<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>Use recursive queries</title>
|
||
</head>
|
||
<body id="rbafyrecursivequeries"><a name="rbafyrecursivequeries"><!-- --></a>
|
||
<img src="./delta.gif" alt="Start of change" /><!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
||
<h1 class="topictitle1">Use recursive queries</h1>
|
||
<div><p>This topic introduces the use of recursive common table expressions
|
||
and recursive views.</p>
|
||
<div class="section"><p>Some applications work with data that is recursive in nature.
|
||
A Bill of Materials (BOM) application, for instance, works with the expansion
|
||
of parts and its component subparts. For example, a chair might be made of
|
||
a seat unit and a leg assembly. The seat unit might consist of a seat and
|
||
two arms. Each of these parts can be further broken down into its subparts
|
||
until there is a list of all the parts needed to build a chair. This type
|
||
of query can be handled by using a recursive common table expression or a
|
||
recursive view.</p>
|
||
</div>
|
||
<div class="section"><div class="p">In the following trip planner examples, airline flights and train
|
||
connections are used to find transportation paths between cities. The following
|
||
table definitions and data are used in the examples.<pre><strong>CREATE TABLE</strong> FLIGHTS (DEPARTURE <strong>CHAR</strong>(20),
|
||
ARRIVAL <strong>CHAR</strong>(20),
|
||
CARRIER <strong>CHAR</strong>(15),
|
||
FLIGHT_NUMBER <strong>CHAR</strong>(5),
|
||
PRICE <strong>INT</strong>)
|
||
|
||
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('New York', 'Paris', 'Atlantic', '234', 400)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Chicago', 'Miami', 'NA Air', '2334', 300)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('New York', 'London', 'Atlantic', '5473', 350)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('London', 'Athens' , 'Mediterranean', '247', 340)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Athens', 'Nicosia' , 'Mediterranean', '2356', 280)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Paris', 'Madrid' , 'Euro Air', '3256', 380)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Paris', 'Cairo' , 'Euro Air', '63', 480)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Chicago', 'Frankfurt', 'Atlantic', '37', 480)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Frankfurt', 'Moscow', 'Asia Air', '2337', 580)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Frankfurt', 'Beijing', 'Asia Air', '77', 480)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Moscow', 'Tokyo', 'Asia Air', '437', 680)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Frankfurt', 'Vienna', 'Euro Air', '59', 200)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Paris', 'Rome', 'Euro Air', '534', 340)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Miami', 'Lima', 'SA Air', '5234', 530)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('New York', 'Los Angeles', 'NA Air', '84', 330)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Los Angeles', 'Tokyo', 'Pacific Air', '824', 530)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Tokyo', 'Hong Kong', 'Asia Air', '94', 330)
|
||
<strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Washington', 'Toronto', 'NA Air', '104', 250)
|
||
|
||
<strong>CREATE TABLE</strong> TRAINS(DEPARTURE <strong>CHAR</strong>(20),
|
||
ARRIVAL <strong>CHAR</strong>(20),
|
||
RAILLINE <strong>CHAR</strong>(15),
|
||
TRAIN <strong>CHAR</strong>(5),
|
||
PRICE <strong>INT</strong>)
|
||
|
||
<strong>INSERT INTO</strong> TRAINS <strong>VALUES</strong>('Chicago', 'Washington', 'UsTrack', '323', 90)
|
||
<strong>INSERT INTO</strong> TRAINS <strong>VALUES</strong>('Madrid', 'Barcelona', 'EuroTrack', '5234', 60)
|
||
<strong>INSERT INTO</strong> TRAINS <strong>VALUES</strong>('Washington' , 'Boston' , 'UsTrack', '232', 50)</pre>
|
||
</div>
|
||
</div>
|
||
<div class="section"><div class="p">Now that the tables are set up, the data can be queried to find
|
||
information about the airline network. Suppose you want to find out what cities
|
||
you can fly to if you start in Chicago, and how many separate flights it will
|
||
take to get there. The following query shows you that information.<pre><strong>WITH</strong> destinations (origin, departure, arrival, flight_count) <strong>AS</strong>
|
||
(<strong>SELECT</strong> a.departure, a.departure, a.arrival, 1
|
||
<strong>FROM</strong> flights a
|
||
<strong>WHERE</strong> a.departure = 'Chicago'
|
||
<strong>UNION ALL</strong>
|
||
<strong>SELECT</strong> r.origin, b.departure, b.arrival, r.flight_count + 1
|
||
<strong>FROM</strong> destinations r, flights b
|
||
<strong>WHERE</strong> r.arrival = b.departure)
|
||
<strong>SELECT</strong> origin, departure, arrival, flight_count
|
||
<strong>FROM</strong> destinations</pre>
|
||
</div>
|
||
</div>
|
||
<div class="section"><p>This query returns the following information:</p>
|
||
|
||
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 1. Results
|
||
of the previous query</caption><thead align="left"><tr valign="bottom"><th valign="bottom" id="d0e240">ORIGIN</th>
|
||
<th valign="bottom" id="d0e242">DEPARTURE</th>
|
||
<th valign="bottom" id="d0e244">ARRIVAL</th>
|
||
<th valign="bottom" id="d0e246">FLIGHT_COUNT</th>
|
||
</tr>
|
||
</thead>
|
||
<tbody><tr><td valign="top" headers="d0e240 ">Chicago</td>
|
||
<td valign="top" headers="d0e242 ">Chicago</td>
|
||
<td valign="top" headers="d0e244 ">Miami</td>
|
||
<td valign="top" headers="d0e246 ">1</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e240 ">Chicago</td>
|
||
<td valign="top" headers="d0e242 ">Chicago</td>
|
||
<td valign="top" headers="d0e244 ">Frankfurt</td>
|
||
<td valign="top" headers="d0e246 ">1</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e240 ">Chicago</td>
|
||
<td valign="top" headers="d0e242 ">Miami</td>
|
||
<td valign="top" headers="d0e244 ">Lima</td>
|
||
<td valign="top" headers="d0e246 ">2</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e240 ">Chicago</td>
|
||
<td valign="top" headers="d0e242 ">Frankfurt</td>
|
||
<td valign="top" headers="d0e244 ">Moscow</td>
|
||
<td valign="top" headers="d0e246 ">2</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e240 ">Chicago</td>
|
||
<td valign="top" headers="d0e242 ">Frankfurt</td>
|
||
<td valign="top" headers="d0e244 ">Beijing</td>
|
||
<td valign="top" headers="d0e246 ">2</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e240 ">Chicago</td>
|
||
<td valign="top" headers="d0e242 ">Frankfurt</td>
|
||
<td valign="top" headers="d0e244 ">Vienna</td>
|
||
<td valign="top" headers="d0e246 ">2</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e240 ">Chicago</td>
|
||
<td valign="top" headers="d0e242 ">Moscow</td>
|
||
<td valign="top" headers="d0e244 ">Tokyo</td>
|
||
<td valign="top" headers="d0e246 ">3</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e240 ">Chicago</td>
|
||
<td valign="top" headers="d0e242 ">Tokyo</td>
|
||
<td valign="top" headers="d0e244 ">Hong Kong</td>
|
||
<td valign="top" headers="d0e246 ">4</td>
|
||
</tr>
|
||
</tbody>
|
||
</table>
|
||
</div>
|
||
</div>
|
||
<div class="section"><p>This recursive query is written in two parts. The first part of
|
||
the common table expression is called the <em>intialization fullselect</em>.
|
||
It selects the first rows for the result set of the common table expression.
|
||
In this example, it selects the two rows in the <em>flights</em> table that
|
||
get you directly to another location from Chicago. It also initializes the
|
||
number of flight legs to one for each row it selects.</p>
|
||
<p>The second part
|
||
of the recursive query joins the rows from the current result set of the common
|
||
table expression with other rows from the original table. It is called the <em>iterative
|
||
fullselect</em>. This is where the recursion is introduced. Notice that the
|
||
rows that have already been selected for the result set are referenced by
|
||
using the name of the common table expression as the table name and the common
|
||
table expression result column names as the column names.</p>
|
||
<p>In this recursive
|
||
part of the query, any rows from the original table that you can get to from
|
||
each of the previously selected arrival cities are selected. A previously
|
||
selected row's arrival city becomes the new departure city. Each row from
|
||
this recursive select increments the flight count to the destination by one
|
||
more flight. As these new rows are added to the common table expression result
|
||
set, they are also fed into the iterative fullselect to generate more result
|
||
set rows. In the data for the final result, you can see that the total number
|
||
of flights is actually the total number of recursive joins (plus 1) it took
|
||
to get to that arrival city.</p>
|
||
<div class="p">A recursive view looks very similar to
|
||
a recursive common table expression. You can write the previous recursive
|
||
common table expression as a recursive view like this:<pre><strong>CREATE VIEW</strong> destinations (origin, departure, arrival, flight_count) <strong>AS</strong>
|
||
<strong>SELECT</strong> departure, departure, arrival, 1
|
||
<strong>FROM</strong> flights
|
||
<strong>WHERE</strong> departure = 'Chicago'
|
||
<strong>UNION ALL</strong>
|
||
<strong>SELECT</strong> r.origin, b.departure, b.arrival, r.flight_count + 1
|
||
<strong>FROM</strong> destinations r, flights b
|
||
<strong>WHERE</strong> r.arrival = b.departure)</pre>
|
||
</div>
|
||
<p>The interactive fullselect part of this view definition
|
||
refers to the view itself. Selection from this view returns the same rows
|
||
as you get from the previous recursive common table expression.</p>
|
||
</div>
|
||
<div class="section"><h4 class="sectiontitle">Example: Two starting cities</h4><p>Now, to make the query
|
||
a bit more complicated, suppose you are willing to fly from either Chicago
|
||
or New York, and you want to know where you could go and how much it would
|
||
cost.</p>
|
||
<pre><strong>WITH</strong> destinations (departure, arrival, connections, cost) <strong>AS</strong>
|
||
(<strong>SELECT</strong> a.departure, a.arrival, 0, price
|
||
<strong>FROM</strong> flights a
|
||
<strong>WHERE</strong> a.departure = 'Chicago' <strong>OR</strong>
|
||
a.departure = 'New York'
|
||
<strong>UNION ALL</strong>
|
||
<strong>SELECT</strong> r.departure, b.arrival, r.connections + 1,
|
||
r.cost + b.price
|
||
<strong>FROM</strong> destinations r, flights b
|
||
<strong>WHERE</strong> r.arrival = b.departure)
|
||
<strong>SELECT</strong> departure, arrival, connections, cost
|
||
<strong>FROM</strong> destinations</pre>
|
||
<p>This query returns the following
|
||
information:</p>
|
||
|
||
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 2. </caption><thead align="left"><tr valign="bottom"><th valign="bottom" id="d0e422">DEPARTURE</th>
|
||
<th valign="bottom" id="d0e424">ARRIVAL</th>
|
||
<th valign="bottom" id="d0e426">CONNECTIONS</th>
|
||
<th valign="bottom" id="d0e428"> COST</th>
|
||
</tr>
|
||
</thead>
|
||
<tbody><tr><td valign="top" headers="d0e422 ">Chicago </td>
|
||
<td valign="top" headers="d0e424 ">Miami</td>
|
||
<td valign="top" headers="d0e426 ">0</td>
|
||
<td valign="top" headers="d0e428 ">300</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">Chicago </td>
|
||
<td valign="top" headers="d0e424 ">Frankfurt</td>
|
||
<td valign="top" headers="d0e426 ">0</td>
|
||
<td valign="top" headers="d0e428 ">480</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">New York</td>
|
||
<td valign="top" headers="d0e424 ">Paris</td>
|
||
<td valign="top" headers="d0e426 ">0</td>
|
||
<td valign="top" headers="d0e428 ">400</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">New York</td>
|
||
<td valign="top" headers="d0e424 ">London</td>
|
||
<td valign="top" headers="d0e426 ">0</td>
|
||
<td valign="top" headers="d0e428 ">350</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">New York</td>
|
||
<td valign="top" headers="d0e424 ">Los Angeles</td>
|
||
<td valign="top" headers="d0e426 ">0</td>
|
||
<td valign="top" headers="d0e428 ">330</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">Chicago</td>
|
||
<td valign="top" headers="d0e424 ">Lima</td>
|
||
<td valign="top" headers="d0e426 ">1</td>
|
||
<td valign="top" headers="d0e428 ">830</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">Chicago</td>
|
||
<td valign="top" headers="d0e424 ">Moscow</td>
|
||
<td valign="top" headers="d0e426 ">1</td>
|
||
<td valign="top" headers="d0e428 ">1,060</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">Chicago</td>
|
||
<td valign="top" headers="d0e424 ">Beijing</td>
|
||
<td valign="top" headers="d0e426 ">1</td>
|
||
<td valign="top" headers="d0e428 ">960</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">Chicago</td>
|
||
<td valign="top" headers="d0e424 ">Vienna</td>
|
||
<td valign="top" headers="d0e426 ">1</td>
|
||
<td valign="top" headers="d0e428 ">680</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">New York</td>
|
||
<td valign="top" headers="d0e424 ">Madrid</td>
|
||
<td valign="top" headers="d0e426 ">1</td>
|
||
<td valign="top" headers="d0e428 ">780</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">New York</td>
|
||
<td valign="top" headers="d0e424 ">Cairo</td>
|
||
<td valign="top" headers="d0e426 ">1</td>
|
||
<td valign="top" headers="d0e428 ">880</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">New York</td>
|
||
<td valign="top" headers="d0e424 ">Rome</td>
|
||
<td valign="top" headers="d0e426 ">1</td>
|
||
<td valign="top" headers="d0e428 ">740</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">New York</td>
|
||
<td valign="top" headers="d0e424 ">Athens</td>
|
||
<td valign="top" headers="d0e426 ">1</td>
|
||
<td valign="top" headers="d0e428 ">690</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">New York</td>
|
||
<td valign="top" headers="d0e424 ">Tokyo</td>
|
||
<td valign="top" headers="d0e426 ">1</td>
|
||
<td valign="top" headers="d0e428 ">860</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">Chicago</td>
|
||
<td valign="top" headers="d0e424 ">Tokyo</td>
|
||
<td valign="top" headers="d0e426 ">2</td>
|
||
<td valign="top" headers="d0e428 ">1,740</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">New York</td>
|
||
<td valign="top" headers="d0e424 ">Nicosia</td>
|
||
<td valign="top" headers="d0e426 ">2</td>
|
||
<td valign="top" headers="d0e428 ">970</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">New York</td>
|
||
<td valign="top" headers="d0e424 ">Hong Kong</td>
|
||
<td valign="top" headers="d0e426 ">2</td>
|
||
<td valign="top" headers="d0e428 ">1,190</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e422 ">Chicago</td>
|
||
<td valign="top" headers="d0e424 ">Hong Kong</td>
|
||
<td valign="top" headers="d0e426 ">3</td>
|
||
<td valign="top" headers="d0e428 ">2,070</td>
|
||
</tr>
|
||
</tbody>
|
||
</table>
|
||
</div>
|
||
<p>For each returned row, the results show the starting departure
|
||
city and the final destination city. It counts the number of connections needed
|
||
rather than the total number of flight and adds up the total cost for all
|
||
the flights.</p>
|
||
</div>
|
||
<div class="section"><h4 class="sectiontitle">Example: Two tables used for recursion</h4><p>Now, suppose
|
||
you start in Chicago but add in transportation by railway in addition to the
|
||
airline flights, and you want to know which cities you can go to.</p>
|
||
<p>The
|
||
following query returns that information:</p>
|
||
<pre><strong>WITH</strong> destinations (departure, arrival, connections, flights, trains, cost) <strong>AS</strong>
|
||
(<strong>SELECT</strong> f.departure, f.arrival, 0, 1, 0, price
|
||
<strong>FROM</strong> flights f
|
||
<strong>WHERE</strong> f.departure = 'Chicago'
|
||
<strong>UNION ALL</strong>
|
||
<strong>SELECT</strong> t.departure, t.arrival, 0, 0, 1, price
|
||
<strong>FROM</strong> trains t
|
||
<strong>WHERE</strong> t.departure = 'Chicago'
|
||
<strong>UNION ALL</strong>
|
||
<strong>SELECT</strong> r.departure, b.arrival, r.connections + 1 , r.flights + 1, r.trains,
|
||
r.cost + b.price
|
||
<strong>FROM</strong> destinations r, flights b
|
||
<strong>WHERE</strong> r.arrival = b.departure
|
||
<strong>UNION ALL</strong>
|
||
<strong>SELECT</strong> r.departure, c.arrival, r.connections + 1 ,
|
||
r.flights, r.trains + 1, r.cost + c.price
|
||
<strong>FROM</strong> destinations r, trains c
|
||
<strong>WHERE</strong> r.arrival = c.departure)
|
||
<strong>SELECT</strong> departure, arrival, connections, flights, trains, cost
|
||
<strong>FROM</strong> destinations</pre>
|
||
<p>This query returns the following
|
||
information:</p>
|
||
|
||
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 3. Results of the previous query</caption><thead align="left"><tr valign="bottom"><th valign="bottom" id="d0e674">DEPARTURE</th>
|
||
<th valign="bottom" id="d0e676">ARRIVAL</th>
|
||
<th valign="bottom" id="d0e678">CONNECTIONS</th>
|
||
<th valign="bottom" id="d0e680">FLIGHTS</th>
|
||
<th valign="bottom" id="d0e682">TRAINS</th>
|
||
<th valign="bottom" id="d0e684">COST</th>
|
||
</tr>
|
||
</thead>
|
||
<tbody><tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Miami</td>
|
||
<td valign="top" headers="d0e678 ">0</td>
|
||
<td valign="top" headers="d0e680 ">1</td>
|
||
<td valign="top" headers="d0e682 ">0</td>
|
||
<td valign="top" headers="d0e684 ">300</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Frankfurt</td>
|
||
<td valign="top" headers="d0e678 ">0</td>
|
||
<td valign="top" headers="d0e680 ">1</td>
|
||
<td valign="top" headers="d0e682 ">0</td>
|
||
<td valign="top" headers="d0e684 ">480</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Washington</td>
|
||
<td valign="top" headers="d0e678 ">0</td>
|
||
<td valign="top" headers="d0e680 ">0</td>
|
||
<td valign="top" headers="d0e682 ">1</td>
|
||
<td valign="top" headers="d0e684 ">90</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Lima</td>
|
||
<td valign="top" headers="d0e678 ">1</td>
|
||
<td valign="top" headers="d0e680 ">2</td>
|
||
<td valign="top" headers="d0e682 ">0</td>
|
||
<td valign="top" headers="d0e684 ">830</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Moscow</td>
|
||
<td valign="top" headers="d0e678 ">1</td>
|
||
<td valign="top" headers="d0e680 ">2</td>
|
||
<td valign="top" headers="d0e682 ">0</td>
|
||
<td valign="top" headers="d0e684 ">1,060</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Beijing</td>
|
||
<td valign="top" headers="d0e678 ">1</td>
|
||
<td valign="top" headers="d0e680 ">2</td>
|
||
<td valign="top" headers="d0e682 ">0</td>
|
||
<td valign="top" headers="d0e684 ">960</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Vienna</td>
|
||
<td valign="top" headers="d0e678 ">1</td>
|
||
<td valign="top" headers="d0e680 ">2</td>
|
||
<td valign="top" headers="d0e682 ">0</td>
|
||
<td valign="top" headers="d0e684 ">680</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Toronto</td>
|
||
<td valign="top" headers="d0e678 ">1</td>
|
||
<td valign="top" headers="d0e680 ">1</td>
|
||
<td valign="top" headers="d0e682 ">1</td>
|
||
<td valign="top" headers="d0e684 ">340</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Boston</td>
|
||
<td valign="top" headers="d0e678 ">1</td>
|
||
<td valign="top" headers="d0e680 ">0</td>
|
||
<td valign="top" headers="d0e682 ">2</td>
|
||
<td valign="top" headers="d0e684 ">140</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Tokyo</td>
|
||
<td valign="top" headers="d0e678 ">2</td>
|
||
<td valign="top" headers="d0e680 ">3</td>
|
||
<td valign="top" headers="d0e682 ">0</td>
|
||
<td valign="top" headers="d0e684 ">1,740</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e674 ">Chicago</td>
|
||
<td valign="top" headers="d0e676 ">Hong Kong</td>
|
||
<td valign="top" headers="d0e678 ">3</td>
|
||
<td valign="top" headers="d0e680 ">4</td>
|
||
<td valign="top" headers="d0e682 ">0</td>
|
||
<td valign="top" headers="d0e684 ">2,070</td>
|
||
</tr>
|
||
</tbody>
|
||
</table>
|
||
</div>
|
||
<p>In this example, there are two parts of the common table expression
|
||
that provide initialization values to the query: one for flights and one for
|
||
trains. For each of the result rows, there are two recursive references to
|
||
get from the previous arrival location to the next possible destination: one
|
||
for continuing by air, the other for continuing by train. In the final results,
|
||
you would see how many connections are needed and how many airline or train
|
||
trips can be taken.</p>
|
||
</div>
|
||
<div class="section"><h4 class="sectiontitle">Example: DEPTH FIRST and BREADTH FIRST options</h4><p>The
|
||
two examples here show the difference in the result set row order based on
|
||
whether the recursion is processed depth first or breadth first.</p>
|
||
<div class="note"><span class="notetitle">Note:</span> The
|
||
search clause is not supported for recursive views. You can define a view
|
||
that contains a recursive common table expression to get this function.</div>
|
||
<p>The
|
||
option to determine the result using breadth first or depth first is a recursive
|
||
relationship sort based on the recursive join column specified for the SEARCH
|
||
BY clause. When the recursion is handled breadth first, all children are processed
|
||
first, then all grandchildren, then all great grandchildren. When the recursion
|
||
is handled depth first, the full recursive ancestry chain of one child is
|
||
processed before going to the next child.</p>
|
||
<p>In both of these cases, you
|
||
specify an extra column name that is used by the recursive process to keep
|
||
track of the depth first or breadth first ordering. This column must be used
|
||
in the ORDER BY clause of the outer query to get the rows back in the specified
|
||
order. If this column is not used in the ORDER BY, the DEPTH FIRST or BREADTH
|
||
FIRST processing option is ignored. </p>
|
||
<p>The selection of which column to
|
||
use for the SEARCH BY column is important. To have any meaning in the result,
|
||
it must be the column that is used in the iterative fullselect to join from
|
||
the initialization fullselect. In this example, ARRIVAL is the column to use.</p>
|
||
<p>The
|
||
following query returns that information:</p>
|
||
<pre><strong>WITH</strong> destinations (departure, arrival, connections, cost) <strong>AS</strong>
|
||
(<strong>SELECT</strong> f.departure, f.arrival, 0, price
|
||
<strong>FROM</strong> flights f
|
||
<strong>WHERE</strong> f.departure = 'Chicago'
|
||
<strong>UNION ALL</strong>
|
||
<strong>SELECT</strong> r.departure, b.arrival, r.connections + 1,
|
||
r.cost + b.price
|
||
<strong>FROM</strong> destinations r, flights b
|
||
<strong>WHERE</strong> r.arrival = b.departure)
|
||
<strong>SEARCH DEPTH FIRST BY</strong> arrival <strong>SET</strong> ordcol
|
||
<strong>SELECT</strong> *
|
||
<strong>FROM</strong> destinations
|
||
<strong>ORDER BY</strong> ordcol</pre>
|
||
<p>This query returns the following information:</p>
|
||
|
||
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 4. Results of the previous query</caption><thead align="left"><tr valign="bottom"><th valign="bottom" id="d0e902">DEPARTURE</th>
|
||
<th valign="bottom" id="d0e904">ARRIVAL</th>
|
||
<th valign="bottom" id="d0e906">CONNECTIONS</th>
|
||
<th valign="bottom" id="d0e908">COST</th>
|
||
</tr>
|
||
</thead>
|
||
<tbody><tr><td valign="top" headers="d0e902 ">Chicago</td>
|
||
<td valign="top" headers="d0e904 ">Miami</td>
|
||
<td valign="top" headers="d0e906 ">0</td>
|
||
<td valign="top" headers="d0e908 ">300</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e902 ">Chicago</td>
|
||
<td valign="top" headers="d0e904 ">Lima</td>
|
||
<td valign="top" headers="d0e906 ">1</td>
|
||
<td valign="top" headers="d0e908 ">830</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e902 ">Chicago</td>
|
||
<td valign="top" headers="d0e904 ">Frankfurt</td>
|
||
<td valign="top" headers="d0e906 ">0</td>
|
||
<td valign="top" headers="d0e908 ">480</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e902 ">Chicago</td>
|
||
<td valign="top" headers="d0e904 ">Moscow</td>
|
||
<td valign="top" headers="d0e906 ">1</td>
|
||
<td valign="top" headers="d0e908 ">1,060</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e902 ">Chicago</td>
|
||
<td valign="top" headers="d0e904 ">Tokyo</td>
|
||
<td valign="top" headers="d0e906 ">2</td>
|
||
<td valign="top" headers="d0e908 ">1,740</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e902 ">Chicago</td>
|
||
<td valign="top" headers="d0e904 ">Hong Kong</td>
|
||
<td valign="top" headers="d0e906 ">3</td>
|
||
<td valign="top" headers="d0e908 ">2,070</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e902 ">Chicago</td>
|
||
<td valign="top" headers="d0e904 ">Beijing</td>
|
||
<td valign="top" headers="d0e906 ">1</td>
|
||
<td valign="top" headers="d0e908 ">960</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e902 ">Chicago</td>
|
||
<td valign="top" headers="d0e904 ">Vienna</td>
|
||
<td valign="top" headers="d0e906 ">1</td>
|
||
<td valign="top" headers="d0e908 ">680</td>
|
||
</tr>
|
||
</tbody>
|
||
</table>
|
||
</div>
|
||
<p>In this result data, you can see that all destinations that are
|
||
generated from the Chicago-to-Miami row are listed before the destinations
|
||
from the Chicago-to-Frankfort row.</p>
|
||
<p>Next, you can run the same query
|
||
but request the result to be ordered breadth first.</p>
|
||
<pre><strong>WITH</strong> destinations (departure, arrival, connections, cost) <strong>AS</strong>
|
||
(<strong>SELECT</strong> f.departure, f.arrival, 0, price
|
||
<strong>FROM</strong> flights f
|
||
<strong>WHERE</strong> f.departure='Chicago'
|
||
<strong>UNION ALL</strong>
|
||
<strong>SELECT</strong> r.departure, b.arrival, r.connections + 1,
|
||
r.cost + b.price
|
||
<strong>FROM</strong> destinations r, flights b
|
||
<strong>WHERE</strong> r.arrival = b.departure)
|
||
<strong>SEARCH BREADTH FIRST BY</strong> arrival <strong>SET</strong> ordcol
|
||
<strong>SELECT</strong> *
|
||
<strong>FROM</strong> destinations
|
||
<strong>ORDER BY</strong> ordcol</pre>
|
||
<p>This query returns the following information:</p>
|
||
|
||
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 5. Results of the previous query</caption><thead align="left"><tr valign="bottom"><th valign="bottom" id="d0e1042">DEPARTURE</th>
|
||
<th valign="bottom" id="d0e1044">ARRIVAL</th>
|
||
<th valign="bottom" id="d0e1046">CONNECTIONS</th>
|
||
<th valign="bottom" id="d0e1048">COST</th>
|
||
</tr>
|
||
</thead>
|
||
<tbody><tr><td valign="top" headers="d0e1042 ">Chicago</td>
|
||
<td valign="top" headers="d0e1044 ">Miami</td>
|
||
<td valign="top" headers="d0e1046 ">0</td>
|
||
<td valign="top" headers="d0e1048 ">300</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e1042 ">Chicago</td>
|
||
<td valign="top" headers="d0e1044 ">Frankfurt</td>
|
||
<td valign="top" headers="d0e1046 ">0</td>
|
||
<td valign="top" headers="d0e1048 ">480</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e1042 ">Chicago</td>
|
||
<td valign="top" headers="d0e1044 ">Lima</td>
|
||
<td valign="top" headers="d0e1046 ">1</td>
|
||
<td valign="top" headers="d0e1048 ">830</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e1042 ">Chicago</td>
|
||
<td valign="top" headers="d0e1044 ">Moscow</td>
|
||
<td valign="top" headers="d0e1046 ">1</td>
|
||
<td valign="top" headers="d0e1048 ">1,060</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e1042 ">Chicago</td>
|
||
<td valign="top" headers="d0e1044 ">Beijing</td>
|
||
<td valign="top" headers="d0e1046 ">1</td>
|
||
<td valign="top" headers="d0e1048 ">960</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e1042 ">Chicago</td>
|
||
<td valign="top" headers="d0e1044 ">Vienna</td>
|
||
<td valign="top" headers="d0e1046 ">1</td>
|
||
<td valign="top" headers="d0e1048 ">680</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e1042 ">Chicago</td>
|
||
<td valign="top" headers="d0e1044 ">Tokyo</td>
|
||
<td valign="top" headers="d0e1046 ">2</td>
|
||
<td valign="top" headers="d0e1048 ">1,740</td>
|
||
</tr>
|
||
<tr><td valign="top" headers="d0e1042 ">Chicago</td>
|
||
<td valign="top" headers="d0e1044 ">Hong Kong</td>
|
||
<td valign="top" headers="d0e1046 ">3</td>
|
||
<td valign="top" headers="d0e1048 ">2,070</td>
|
||
</tr>
|
||
</tbody>
|
||
</table>
|
||
</div>
|
||
<p>In this result data, you can see that all the direct connections
|
||
from Chicago are listed before the connecting flights. The data is identical
|
||
to the results from the previous query, but in a breadth first order.</p>
|
||
</div>
|
||
<div class="section"><h4 class="sectiontitle">Example: Cyclic</h4><p>The key to any recursive process,
|
||
whether it is a recursive programming algorithm or querying recursive data,
|
||
is that the recursion must be finite. If not, you will get into a never ending
|
||
loop. The CYCLE option allows you to safeguard against cyclic data. Not only
|
||
will it terminate repeating cycles but it also allows you to optionally output
|
||
a cycle mark indicator that may lead you to find cyclic data. </p>
|
||
<div class="note"><span class="notetitle">Note:</span> The
|
||
cycle clause is not supported for recursive views. You can define a view that
|
||
contains a recursive common table expression to get this function.</div>
|
||
<p>For
|
||
a final example, suppose we have a cycle in the data. By adding one more row
|
||
to the table, there is now a flight from Cairo to Paris and one from Paris
|
||
to Cairo. Without accounting for possible cyclic data like this, it is quite
|
||
easy to generate a query that will go into an infinite loop processing the
|
||
data.</p>
|
||
<p>The following query returns that information:</p>
|
||
<pre><strong>INSERT INTO</strong> FLIGHTS <strong>VALUES</strong>('Cairo', 'Paris', 'Euro Air', '1134', 440)
|
||
|
||
|
||
<strong>WITH</strong> destinations (departure, arrival, connections, cost, itinerary) <strong>AS</strong>
|
||
(<strong>SELECT</strong> f.departure, f.arrival, 1, price,
|
||
<strong>CAST</strong>(f.departure <strong>CONCAT</strong> f.arrival <strong>AS VARCHAR</strong>(2000))
|
||
<strong>FROM</strong> flights f
|
||
<strong>WHERE</strong> f.departure = 'New York'
|
||
<strong>UNION ALL</strong>
|
||
<strong>SELECT</strong> r.departure, b.arrival, r.connections + 1 ,
|
||
r.cost + b.price, <strong>CAST</strong>(r.itinerary <strong>CONCAT</strong> b.arrival <strong>AS</strong> <strong>VARCHAR</strong>(2000))
|
||
<strong>FROM</strong> destinations r, flights b
|
||
<strong>WHERE</strong> r.arrival = b.departure)
|
||
<strong>CYCLE</strong> arrival <strong>SET</strong> cyclic_data <strong>TO</strong> '1' <strong>DEFAULT</strong> '0'
|
||
<strong>SELECT</strong> departure, arrival, itinerary, cyclic_data
|
||
<strong> FROM</strong> destinations
|
||
<strong>ORDER BY</strong> cyclic_data</pre>
|
||
<p>This query returns the following
|
||
information:</p>
|
||
|
||
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" frame="border" border="1" rules="all"><caption>Table 6. Results of the previous
|
||
query</caption><thead align="left"><tr valign="bottom"><th valign="bottom" width="14.000000000000002%" id="d0e1224">DEPARTURE</th>
|
||
<th valign="bottom" width="14.000000000000002%" id="d0e1226">ARRIVAL</th>
|
||
<th valign="bottom" width="57.99999999999999%" id="d0e1228">ITINERARY</th>
|
||
<th valign="bottom" width="14.000000000000002%" id="d0e1230">CYCLIC_DATA</th>
|
||
</tr>
|
||
</thead>
|
||
<tbody><tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">Paris</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York Paris</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">0</td>
|
||
</tr>
|
||
<tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">London</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York London</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">0</td>
|
||
</tr>
|
||
<tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">Los Angeles</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York Los Angeles</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">0</td>
|
||
</tr>
|
||
<tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">Madrid</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York Paris Madrid</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">0</td>
|
||
</tr>
|
||
<tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">Cairo</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York Paris Cairo</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">0</td>
|
||
</tr>
|
||
<tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">Rome</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York Paris Rome</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">0</td>
|
||
</tr>
|
||
<tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">Athens</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York London Athens</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">0</td>
|
||
</tr>
|
||
<tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">Tokyo</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York Los Angeles Tokyo</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">0</td>
|
||
</tr>
|
||
<tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">Paris</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York Paris Cairo Paris</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">1</td>
|
||
</tr>
|
||
<tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">Nicosia</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York London Athens Nicosia</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">0</td>
|
||
</tr>
|
||
<tr><td valign="top" width="14.000000000000002%" headers="d0e1224 ">New York</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1226 ">Hong Kong</td>
|
||
<td valign="top" width="57.99999999999999%" headers="d0e1228 ">New York Los Angeles Tokyo Hong
|
||
Kong</td>
|
||
<td valign="top" width="14.000000000000002%" headers="d0e1230 ">0</td>
|
||
</tr>
|
||
</tbody>
|
||
</table>
|
||
</div>
|
||
<p>In this example, the ARRIVAL column is defined in the CYCLE clause
|
||
as the column to use for detecting a cycle in the data. When a cycle is found,
|
||
a special column, CYCLIC_DATA in this case, is set to the character value
|
||
of '1' for the cycling row in the result set. All other rows will contain
|
||
the default value of '0'. When a cycle on the ARRIVAL column is found, processing
|
||
will not proceed any further in the data so the infinite loop will not happen.
|
||
To see if your data actually has a cyclic reference, the CYCLIC_DATA column
|
||
can be referenced in the outer query.</p>
|
||
</div>
|
||
</div>
|
||
<div>
|
||
<div class="familylinks">
|
||
<div class="parentlink"><strong>Parent topic:</strong> <a href="rbafytexas.htm" title="Learn a variety of ways of tailoring your query to gather data using the SELECT statement. One way to do this is to use the SELECT statement in a program to retrieve a specific row (for example, the row for an employee). Furthermore, you can use clauses to gather data in a specific way.">Retrieve data using the SELECT statement</a></div>
|
||
</div>
|
||
</div>
|
||
<img src="./deltaend.gif" alt="End of change" /></body>
|
||
</html> |