Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: Direct and indirect foreign key relationships in SQL or Pl/Sql
Here's one way.
It uses a temporary table, as a CONNECT BY cannot be done on the %_CONSTRAINTS view.
Jared
create test data
drop table t3; drop table t2; drop table t1; create table t1 ( pk number ); create table t2 ( pk number, t1_pk number );create table t3 ( pk number, t2_pk number ); create table t4 ( pk number, t3_pk number );
alter table t1 add constraint t1_pk
primary key(pk);
alter table t2 add constraint t2_pk
primary key(pk);
alter table t3 add constraint t3_pk
primary key(pk);
alter table t4 add constraint t4_pk
primary key(pk);
alter table t2 add constraint t2_t1_pk
foreign key(t1_pk)
references t1(pk);
alter table t3 add constraint t3_t2_pk
foreign key(t2_pk)
references t2(pk);
alter table t4 add constraint t4_t3_pk
foreign key(t3_pk)
references t3(pk);
create global temporary table r1
on commit delete rows
--create table r1
as
select
c.table_name child
, p.table_name parent
, p.constraint_name
, c.constraint_name fk_constraint
, c.delete_rule
insert into r1
select *
from
(
select
c.table_name child
, p.table_name parent
, p.constraint_name
, c.constraint_name fk_constraint
, c.delete_rule
and c.constraint_type in ('R') and c.status = 'ENABLED' and p.owner = c.r_owner and p.constraint_name = c.r_constraint_name) a
col child format a10
col parent format a20
col pad format a20
col constraint_name format a30
col r_constraint_name format a30
col tlevel noprint
set line 120
select
tlevel
, parent
, constraint_name
, child
, fk_constraint
, delete_rule
from ( select level tlevel , lpad(parent, level*3) parent , constraint_name , child , fk_constraint , delete_rule from r1 start with parent = 'T1' connect by prior child = parent
"Krishnaswamy, Ranganath" <Ranganath.Krishnaswamy_at_blr.hpsglobal.com>
Sent by: root_at_fatcity.com
12/18/2002 11:13 PM
Please respond to ORACLE-L
To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> cc: Subject: Direct and indirect foreign key relationships in SQL or Pl/Sql
Hi all,
How do I find out the direct and indirect foreign keyrelationships?
Thanks and Regards,
Ranganath
WARNING: The information in this message is confidential and may be
legally
privileged. It is intended solely for the addressee. Access to this
message
by anyone else is unauthorised. If you are not the intended recipient,
any
disclosure, copying, or distribution of the message, or any action or
omission taken by you in reliance on it, is prohibited and may be
unlawful.
Please immediately contact the sender if you have received this message in
error. Thank you.
-- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Krishnaswamy, Ranganath INET: Ranganath.Krishnaswamy_at_blr.hpsglobal.com Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: 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). -- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: INET: Jared.Still_at_radisys.com Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: 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 Fri Dec 20 2002 - 13:14:39 CST
![]() |
![]() |