Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 

 
 

CONNECT BY LOOP

Oracle Tips by Laurent Schneider

 

Laurent Schneider is considered one of the top Oracle SQL experts, and he is the author of the book "Advanced SQL Programming" by Rampant TechPress.  The following is an excerpt from the book.

 

CONNECT BY LOOP

A loop in user data generates an "ORA-01436: CONNECT BY loop in user data" error. A loop is defined in the Oracle Database SQL Language Reference (11.1) documentation as:

"A loop occurs if one row is both the parent (or grandparent or direct ancestor) and a child (or a grandchild or a direct descendent) of another row":

WITH
   T
AS
(
   SELECT
      'JOHN' EMPLOYEE,
      'JACK' MANAGER
   FROM
      DUAL
   UNION ALL
   SELECT
      'JACK' EMPLOYEE,
      'JOHN' MANAGER
   FROM
      DUAL
)
SELECT
   EMPLOYEE,
   MANAGER
FROM
   T
CONNECT BY
   PRIOR EMPLOYEE = MANAGER; 

ERROR:
ORA-01436: CONNECT BY loop in user data

There is a loop in the user data because John is both the manager and the employee of Jack.

CONNECT BY NOCYCLE and CONNECT_BY_ISCYCLE

With the 10g keyword NOCYCLE, hierarchical queries detect loops and do not generate errors. CONNECT_BY_ISCYCLEpseudo-column is a flag that can be used to detect which row is cycling.

WITH
   T
AS
(
   SELECT
      'JOHN' EMPLOYEE,
      'JACK' MANAGER
   FROM
      DUAL
   UNION ALL
   SELECT
      'JACK' EMPLOYEE,
      'JOHN' MANAGER
   FROM
      DUAL
)
SELECT
   SYS_CONNECT_BY_PATH (EMPLOYEE,'/') as EMPLOYEE,
   MANAGER,
   CONNECT_BY_ISCYCLE
FROM
   T
CONNECT BY
NOCYCLE
   PRIOR EMPLOYEE = MANAGER;
 

EMPLOYEE       MANAGER CONNECT_BY_ISCYCLE
-------------- ------- ------------------
/JOHN          JACK                     0
/JOHN/JACK     JOHN                     1
/JACK          JOHN                     0
/JACK/JOHN     JACK                     1

Sub-employee Jack is cycling because he is the child and parent of John. John is also cycling, because he is the child and parent of Jack.

CONNECT BY without PRIOR

A very popular usage of hierarchical query, documented by Vadim Tropashko in his book SQL Design Patterns, is to generate rows.

SELECT
   SYS_CONNECT_BY_PATH(DUMMY, '/')
FROM
   DUAL
CONNECT BY
   LEVEL<4;

SYS_CONNECT_BY_PATH(DUMMY,'/')
--------------------------------
/X
/X/X
/X/X/X
 

NOTE:  According to the official documentation, PRIOR is mandatory.
Oracle Database SQL Language Reference (11.1)
?In a hierarchical query, one expression in the CONNECT BY condition must be qualified by the PRIOR operator?. 

The single row of dual is both the parent and the child of itself but no loop is generated. It is a very efficient way to generate rows.

CONNECT_BY_ISLEAF

The 10g pseudo-column CONNECT_BY_ISLEAFidentifies rows that do not have descendants.

SELECT
   SYS_CONNECT_BY_PATH(ENAME, '/')
FROM
   EMP
WHERE
   CONNECT_BY_ISLEAF=1
START WITH
   MGR IS NULL
CONNECT BY
   PRIOR EMPNO=MGR;

SYS_CONNECT_BY_PATH(ENAME,'/')
-----------------------------------
/KING/JONES/SCOTT/ADAMS
/KING/JONES/FORD/SMITH
/KING/BLAKE/ALLEN
/KING/BLAKE/WARD
/KING/BLAKE/MARTIN
/KING/BLAKE/TURNER
/KING/BLAKE/JAMES
/KING/CLARK/MILLER

Only complete paths from the ancestor where MGR is null to the last descendants are displayed.

WHERE and JOIN

Oracle detects in the where clause if the condition is a join condition or a not-join condition. There is a big difference between a join and a not-join condition in that the former is performed before the building of the hierarchy and the later is performed after the hierarchy.

SELECT
   SYS_CONNECT_BY_PATH(EMP.ENAME, '/') P
FROM
   EMP,
   TABLE
   (
      SYS.ODCINUMBERLIST(20, 30)
   ) T
WHERE
   EMP.DEPTNO=T.COLUMN_VALUE
CONNECT BY
   PRIOR EMP.EMPNO=EMP.MGR
START WITH
   MGR IS NULL;

no rows selected

Oracle detects the join and selects the matching rows. 

Only rows from the departments 20 and 30 are used to build the hierarchy. No row in the departments 20 and 30 satisfies the condition MGR IS NULL.

SELECT
   SYS_CONNECT_BY_PATH(EMP.ENAME, '/') P
FROM
   EMP 
WHERE
   EMP.DEPTNO IN (20, 30)
CONNECT BY
   PRIOR EMPNO=MGR
START WITH
   MGR IS NULL;

P
---------------------------
/KING/JONES
/KING/JONES/SCOTT
/KING/JONES/SCOTT/ADAMS
/KING/JONES/FORD
/KING/JONES/FORD/SMITH
/KING/BLAKE
/KING/BLAKE/ALLEN
/KING/BLAKE/WARD
/KING/BLAKE/MARTIN
/KING/BLAKE/TURNER
/KING/BLAKE/JAMES

The condition is not a join; therefore, the hierarchy is built with all rows. Later, the condition is applied to the children.

SELECT
   P
FROM
   (
      SELECT
         SYS_CONNECT_BY_PATH(EMP.ENAME, '/') P,
         DEPTNO
      FROM
         EMP 
      CONNECT BY
         PRIOR EMPNO=MGR
      START WITH
         MGR IS NULL
   )
WHERE
   DEPTNO IN (20, 30);

P
---------------------------
/KING/JONES
/KING/JONES/SCOTT
/KING/JONES/SCOTT/ADAMS
/KING/JONES/FORD
/KING/JONES/FORD/SMITH
/KING/BLAKE
/KING/BLAKE/ALLEN
/KING/BLAKE/WARD
/KING/BLAKE/MARTIN
/KING/BLAKE/TURNER
/KING/BLAKE/JAMES

The same query again appears with a subquery. This time, the hierarchy is built with all rows in the subquery and the condition applies to the main query.

The JOINsyntax allows more flexibility to define what should be processed before the hierarchy and what should be processed after.

SELECT
   SYS_CONNECT_BY_PATH(ENAME, '/') P
FROM
   EMP
JOIN
   DUAL
ON
(
   HIREDATE > DATE '1981-06-01'
)
WHERE
   JOB='CLERK'
CONNECT BY
   PRIOR EMPNO=MGR
START WITH
   MGR IS NULL; 

P
--------------------
/KING/CLARK/MILLER

The DUALtable is joined to EMP. The ONclause is defined before computing the hierarchy, so the whole tree will contain only employees hired after June 1, 1981. The WHERE clause returns only the clerks. The path from the president to the clerks exclusively contains new employees. 


 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.