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 


 

 

 


 

 

 
 

dba_dependencies scripts


Oracle Tips by Burleson Consulting

Updated 22 July 2015

The dba_dependencies view describes all dependencies in the database between procedures, packages, functions, package bodies, and triggers, including dependencies on views created without any database links.

Also, see these scripts that use dba_dependencies to find all tables that are inside stored procedures and functions.

Also related is the utldtree utility procedure for identifying object dependencies.

Oracle expert Jared Still has a wonderful interactive SQL*Plus script for tracking dependencies:

prompt Dependencies for Owner?:

col cowner noprint new_value uowner
set term off feed off
select upper('&1') cowner from dual;
set term on feed on

prompt Dependencies for Object?:

col cobject noprint new_value uobject
set term off feed off
select upper('&2') cobject from dual;
set term on feed on

set line 142 pages 60

column display_parent format a58
column display_child format a58
column referenced_owner noprint
column referenced_object noprint
column referenced_type noprint
column owner noprint
column object noprint
column type noprint
column last_ddl_time format a22 head 'CHILD DDL TIME'

undef 1 2

with dependencies as (
        -- top down through the heirarchy
        select /*+ no_merge */
                referenced_type || ' "' || referenced_owner || '"."' ||
                referenced_name || '"' as parent,
                type || ' "' || owner || '"."' || name || '"' as child,
                level hlevel,
                referenced_owner, referenced_name, referenced_type,
                owner, name, type
        from dba_dependencies
        start with
                referenced_owner = '&&uowner'
                and referenced_name = '&&uobject'
        connect by
                referenced_owner = prior owner
                and referenced_name = prior name
                and referenced_type = prior type
        union
        -- bottom up through the heirarchy
        select /*+ no_merge */
                referenced_type || ' "' || referenced_owner || '"."' ||
                referenced_name || '"' as parent,
                type || ' "' || owner || '"."' || name || '"' as child,
                level hlevel,
                referenced_owner, referenced_name, referenced_type,
                owner, name, type
        from dba_dependencies
        start with
                owner = '&&uowner'
                and name = '&&uobject'
        connect by
                owner = prior referenced_owner
                and name = prior referenced_name
                and type = prior referenced_type
        order by 1, 2
)
select lpad(' ',2*d.hlevel,' ') || d.parent display_parent, d.child
display_child, o.last_ddl_time
from dependencies d, dba_objects o
where o.owner = d.owner
and o.object_type = d.type
and d.name = o.object_name
order by parent, child
/

 

Here is another  useful script for tracking object dependencies with dba_dependencies:

column c1 heading "object|level"         format a16
column c2 heading "object|name"          format a40
column c3 heading "referencing|object"   format a40

select
   lpad (' ', 2 * (level - 1)) || to_char (level, '999') as c1,
   owner || '.' || name || ' (' || type || ')' as c2,
   referenced_owner || '.' || referenced_name || ' (' || referenced_type || ')' as c3
from
   dba_dependencies
start with
   owner = 'SYS'
and
   name = 'my_tablename'
connect by prior
   referenced_owner = owner
and prior
   referenced_name = name
and prior
   referenced_type = type
and
   type = 'TABLE';

 


set lines 132

select distinct
   owner,
   name,
   referenced_name
from
   dba_dependencies
where
   type in ('PACKAGE BODY','PROCEDURE','TRIGGER')
and
   referenced_type = 'SEQUENCE';

select
   referenced_name,
   referenced_type
from
   dba_dependencies
where
   name='my_tablename';


select
   referenced_name,
   referenced_type
from
   dba_dependencies
where
   name='CUSTOMER'
and
   referenced_type='TABLE'
 

 
Get the Complete
Oracle SQL Tuning Information 

The landmark book "Advanced Oracle SQL Tuning  The Definitive Reference"  is filled with valuable information on Oracle SQL Tuning. This book includes scripts and tools to hypercharge Oracle 11g performance and you can buy it for 30% off directly from the publisher.

 


 

 

��  
 
 
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.