Skip to content

Commit

Permalink
Merge pull request #208 from HuangSongZ/master
Browse files Browse the repository at this point in the history
Hierarchical Query identifys the leaves
  • Loading branch information
okbob authored Jan 13, 2023
2 parents 76d8366 + a0e7545 commit 25e9201
Showing 1 changed file with 87 additions and 0 deletions.
87 changes: 87 additions & 0 deletions doc/sql_migration/sql_migration04.md
Original file line number Diff line number Diff line change
Expand Up @@ -870,6 +870,93 @@ The example below shows migration when the root data is displayed.
</tbody>
</table>

##### 4.2.3.7 Hierarchical Query identifys the leaves

**Functional differences**

- **Oracle database**
- Specifying CONNECT_BY_ISLEAF in the select list of a hierarchical query can identify the leaf rows. This returns 1 if the current row is a leaf. Otherwise it returns 0.
- **PostgreSQL**
- CONNECT_BY_ISLEAF cannot be specified.

**Migration procedure**

In a recursive query that uses a WITH clause, the leaf can be checked using a sub-query so that the same result is returned. Use the following procedure to perform migration:

1. Replace the hierarchical query with syntax that uses a recursive query (WITH clause).
2. Add a sub-query to the column list of the query result of the WITH clause.

The following shows the conversion format containing rootName.

~~~
WITH RECURSIVE queryName(
columnUsed1, columnUsed2
) AS
( SELECT columnUsed, columnUsed2
FROM targetTableOfHierarchicalQuery
UNION ALL
SELECT columnUsed(qualified by n), columnUsed2(qualified by n)
FROM targetTableOfHierarchicalQuery n,
queryName w
WHERE conditionalExprOfConnectByClause
)
SELECT *,
CASE WHEN EXISTS(select * from queryName p where p.columnUsed1 = e.columnUsed2)
THEN 0 ELSE 1 END
as is_leaf
FROM queryName e;
~~~

For conditionalExprOfConnectByClause, use w to qualify the part qualified by PRIOR.

**Migration example**

The example below shows migration when the leaf data is displayed.
<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code>SELECT staff_id, name, <b>CONNECT_BY_ISLEAF </b>
FROM staff_table
START WITH staff_id = '1001'
CONNECT BY PRIOR staff_id = manager_id;
<br>
<br>
<br>
<br>
<br>
<br>
<br>
<br>
</code></pre>
</td>

<td align="left">
<pre><code>WITH RECURSIVE staff_table_w( staff_id,
name ) AS
( SELECT staff_id, name
FROM staff_table
UNION ALL
SELECT n.staff_id, n.name
FROM staff_table n, staff_table_w w
WHERE w.staff_id = n.manager_id
)
SELECT staff_id, name,
<b>CASE WHEN EXISTS(select 1 from staff_table_w p where p.manager_id = e.staff_id)
THEN 0 ELSE 1 END
as is_leaf </b>
FROM staff_table_w e;</code></pre>
</td>
</tr>
</tbody>
</table>

#### 4.2.4 MINUS

**Description**
Expand Down

0 comments on commit 25e9201

Please sign in to comment.