Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 

SQLStudies

My name is Kenneth Fisher and I am Senior DBA for a large (multi-national) insurance company. I have been working with databases for over 20 years starting with Clarion and Foxpro. I’ve been working with SQL Server for 12 years but have only really started “studying” the subject for the last 3. I don’t have any real "specialities" but I enjoy trouble shooting and teaching. Thus far I’ve earned by MCITP Database Administrator 2008, MCTS Database Administrator 2005, and MCTS Database Developer 2008. I’m currently studying for my MCITP Database Developer 2008 and should start in on the 2012 exams next year. My blog is at www.sqlstudies.com.

How do I find all stored procedures or views that use a specific table?

Many years ago when I was still working on SQL 2000 I occasionally needed to find all stored procedures and views that referenced a certain table.  After some research I found the system table syscomments.  This table has a column “text” that contains the “Actual text of the SQL definition statement.”  Using the following statement I was able to find every piece of code in the database using the table ‘ABC’.

SELECT DISTINCT OBJECT_SCHEMA_NAME(id), OBJECT_NAME(id) FROM syscomments WHERE [text] LIKE '%ABC%'

This has a few problems.  First ABC could be listed in the comments and not in any real code.  Second a table ABC_DEF or a view vw_ABC, for example, will give false positives.  Third if the stored procedure, view etc is encrypted then it won’t be included in the result set.

As of SQL 2005 the table syscomments became a system view and was depreciated.  Microsoft added the system view sys.sql_modules to take its place.  The code I used in SQL 2005 was as follows:

SELECT OBJECT_SCHEMA_NAME(object_id), OBJECT_NAME(object_id) FROM sys.sql_modules WHERE [definition] LIKE '%ABC%'

The size of the field that contains the SQL definition is the only major change that I’ve noticed between the two versions.  The field sys.sql_modules.definition is a nvarchar(max) instead of the nvarchar(4000) for sys.syscomments.text.  This means that SQL stores long pieces of code in a single row instead multiple.  As a result the DISTINCT in the query is no longer needed.

In SQL 2008 the DMV (a Data Management Function really) sys.dm_sql_referencing_entities was added.  This DMV returns any object that references the object you pass it.

SELECT * FROM sys.dm_sql_referencing_entities('dbo.ABC', 'OBJECT')

While either of the older two pieces of code will still work there is a big advantage to using the DMV.  There are no longer false positives from comments, ‘ABC_DEF’ or ‘vw_ABC’ type entries.  I believe the result set includes encrypted referencing objects as well, although I haven’t actually tested it.  Also by requiring the schema the DMV enforces more precision in the search than the older versions.   SchemaA.Table1 and SchemaB.Table1 are two different objects after all.

I don’t expect 2012 to add anything really new to this, but if it does I’ll be sure to add it here.

Of course in all cases if you only want a specific type of object (stored procedures for example) in your result set then you have to either write a function (see my previous post here for an example), use OBJECTPROPERTY(IsProcedure, IsView etc) (2000+),  OBJECTPROPERTYEX(BaseType) (2005+), or join with sys.objects, sys.procedures, sys.views etc.

PS Also in 2008+ there is also a DMV sys.dm_sql_referenced_entities which is a handy way to see all objects referenced by the specified stored procedure, view, function etc passed into the DMV.


Comments

Leave a comment on the original post [sqlstudies.com, opens in a new window]

Loading comments...