Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: SQL Brain Teaser Challenge
Hi Steve,
You can get the below query to work in 8.1.7 (not sure about previous
versions) by setting the undoc parameter _new_connect_by_enabled = true
and can be set for a session
SELECT *
FROM (SELECT * FROM treenode ORDER BY parentid, nodeorder)
START WITH parentid=0
CONNECT BY PRIOR ID = parentid
You can also use sys_connect_by_path feature in 9i which gives you the entire hierarchy path (can be used in 8i with the above undoc parameter)
For eg:
select sys_connect_by_path(parent_id,'/')
from treenode
start with parent_id = 0
connect by prior id = parent_id
will give you a output like
0/1/9 0/1/2 0/1/2/4
...etc
As always setting an undoc parameter is not advisable unless instructed by Oracle support :-)
Hope this helps.
Regards,
Madhavan
http://www.dpapps.com
--
Madhavan Amruthur
DecisionPoint Applications
--
http://fastmail.fm - The holy hand grenade of email services
--
Please see the official ORACLE-L FAQ: http://www.orafaq.com
--
Author: Madhavan Amruthur
INET: mad5698_at_fastmail.fm
Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting servicesto: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing). Received on Wed Nov 06 2002 - 10:23:42 CST
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message