SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Finding Dependencies of Objects


Finding Dependencies of Objects

Author
Message
vignesh.ms
vignesh.ms
SSC Eights!
SSC Eights! (836 reputation)SSC Eights! (836 reputation)SSC Eights! (836 reputation)SSC Eights! (836 reputation)SSC Eights! (836 reputation)SSC Eights! (836 reputation)SSC Eights! (836 reputation)SSC Eights! (836 reputation)

Group: General Forum Members
Points: 836 Visits: 516
Hi There,

I need to do some clean up activities in my databases... So i intended to drop unwanted tables and views.

for that I need to find, whether the table being used by any other objects ?

How could I achieve it?

thanks in advance
Lowell
Lowell
SSC Guru
SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)

Group: General Forum Members
Points: 72254 Visits: 40942
procs and views referencing your tables are only part of the puzzle;
applications can have dependencies on those tables, and applications can reference tables that are never used.

there's a handy chartabout how 45% of application improvements get added but are never used, and those improvements most likely reference objects int ehd atabase which need to exist, but are never used as well.

you'll need to search applcation code in addition to the database.



here's a handy script for you for the SQL side:

SELECT
depz.referenced_schema_name,
depz.referenced_entity_name,
objz.type_desc,
object_schema_name(depz.referencing_id) As ReferencingSchema,
object_name(depz.referencing_id) AS ReferencingObject,
colz.name AS ColumnName
FROM sys.sql_expression_dependencies depz
INNER JOIN sys.objects objz ON depz.referenced_id=objz.object_id
LEFT OUTER JOIN sys.columns colz ON objz.object_id = colz.object_id
AND colz.column_id = referencing_minor_id
--WHERE referencing_id = OBJECT_ID(N'MyTable');
WHERE referenced_id = OBJECT_ID(N'EDLogDetail');
--AND colz.name = 'EmployeeNumber'



Lowell
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
Jason Deyalsingh
Jason Deyalsingh
SSC Rookie
SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)SSC Rookie (28 reputation)

Group: General Forum Members
Points: 28 Visits: 77
As far as identifying application dependencies go, one technique is to run SQL server profiler while the application is being used (It's resource intensive, so ideally you'd want to run this in a test environment). If feasible, you can perhaps have someone run through all the major functions in a test environment, while profiler is running. Then inspect the traces to identify all the objects which the application uses. I can provide more details if you need.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search