Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Searching stored procedure for table name but ignoring comments Expand / Collapse
Author
Message
Posted Sunday, November 28, 2010 4:43 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, March 29, 2012 2:34 AM
Points: 4, Visits: 18
Hi All,

Thanks to others who have posted helpful tips I have a way of searching through stored procedures to list those that reference a specific table (one way listed below ) but ideally I would like to exclude those table references that are listed in comments or hashed out and no longer part of the active body of the procedure ..

Currently can't see a way to do this - has anyone got an idea on how to approach this or have actioned this themselves ?

It may be this is just not possible searching through the sys tables ..but thought I would just ask

Any feedback/tips much appreciated

Thanks,
Ralph

SELECT DISTINCT SO.NAME
FROM SYSOBJECTS SO (NOLOCK)
WHERE SO.TYPE = 'P'
AND SO.NAME LIKE @StringToSearch
ORDER BY SO.Name
Post #1027035
Posted Sunday, November 28, 2010 6:47 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 10:26 AM
Points: 13,884, Visits: 28,278
Unless you get incredibly sophisticated with your search algorithms, possibly using CLR or something, to determine if the string you're looking at is contained within a comment, of either type, line comments or block comments, no, there's no way to do this with a straight-forward T-SQL statement.

----------------------------------------------------
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood..." Theodore Roosevelt
The Scary DBA
Author of: SQL Server Query Performance Tuning
SQL Server 2012 Query Performance Tuning
SQL Server 2008 Query Performance Tuning Distilled
and
SQL Server Execution Plans

Product Evangelist for Red Gate Software
Post #1027052
Posted Sunday, November 28, 2010 9:29 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 1:53 PM
Points: 35,366, Visits: 31,905
Wouldn't a search of dependencies tell you?

{edit} Bad suggestion on my part. Like Steve says below, it's NOT 100% guaranteed. It's always worked for me in the past but that's only because I (apparently) got lucky and followed "the rules". I knew that dynamic SQL wouldn't register but I didn't know the "fault" induced by deferred naming, etc.

See sys.sql_dependencies in Books Online for more info on why a dependency may or may not exist.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1027059
Posted Sunday, November 28, 2010 10:06 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: Administrators
Last Login: Yesterday @ 12:34 PM
Points: 31,181, Visits: 15,626
If the dependency tree in SQL Server is up to date it works, but it isn't guaranteed. I'd agree with Grant, there isn't an easy way to do this. What you could do is just search, and if you find tables in stored procedure comments, go through and clean up the comments to change the table name in there to something that won't match.






Follow me on Twitter: @way0utwest

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1027067
Posted Sunday, November 28, 2010 11:31 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 1:53 PM
Points: 35,366, Visits: 31,905
Here's what Steve means about "if they're up to date". This comes from Books Online under "sys.sql_dependencies"...

Remarks
Dependencies are established during CREATE only if the referenced (independent) entity exists at the time that the referencing (dependent) object is created. Due to deferred name resolution, the referenced entity need not exist at the time of creation. In this case, a dependency row is not created. Moreover, entities referenced through dynamic SQL do not establish dependencies.

If the referenced (independent) entity is dropped using DROP, the dependency row is deleted automatically. To re-establish the dependency row, you will need to re-create both, using CREATE, in the correct dependency order.

Both schema-bound and non-schema-bound dependencies are tracked for objects. Dependencies on types, XML schema collections, and partition functions are only tracked for schema-bound dependencies. CHECK constraints, defaults, and computed column references are implicitly schema-bound.


Also note that further reading reveals that anything contained in dynamic SQL is NOT included, ever.

So... with all that in mind, I'll have to withdraw my suggestion because it was a bad one.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1027079
Posted Sunday, November 28, 2010 11:49 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, March 29, 2012 2:34 AM
Points: 4, Visits: 18
Hi
I did doubt there was a way to do this using T-SQL but really appreciate the feedback from everyone - I'll look at Steve's suggestion of performing the search then go through and clean up the comments to change the table name in there to something that doesn't match.

Many thanks all

Ralph
Post #1027083
Posted Sunday, November 28, 2010 12:05 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: 2 days ago @ 1:11 PM
Points: 12,905, Visits: 32,161
I have this snippets saved which might help; it's using a pair of loops table to strip out any comments , so you can then search just the remaining proc definition;
declare @definition varchar(max),
@objectname varchar(255),
@vbCrLf CHAR(2)
SET @vbCrLf = CHAR(13) + CHAR(10)

SET @objectname = 'sp_getDDL'
select @definition = definition + 'GO' + @vbcrlf from sys.sql_modules where [object_id] = object_id(@objectname)
--'objective: strip out comments.
--first loop is going to look for pairs of '/*' and '*/', and STUFF them with empty space.
--second loop is going to look for sets of '--' and vbCrLf and STUFF them with empty space.
--===== Replace all '/*' and '*/' pairs with nothing
WHILE CHARINDEX('/*',@definition) > 0
SELECT @definition = STUFF(@definition,
CHARINDEX('/*',@definition),
CHARINDEX('*/',@definition) - CHARINDEX('/*',@definition) + 2, --2 is the length of the search term
'')
--===== Replace all single line comments
WHILE CHARINDEX('--',@definition) > 0
AND CHARINDEX(@vbCrLf,@definition,CHARINDEX('--',@definition)) > CHARINDEX('--',@definition)
SELECT @definition = STUFF(@definition,
CHARINDEX('--',@definition),
CHARINDEX(@vbCrLf,@definition,CHARINDEX('--',@definition)) - CHARINDEX('--',@definition) + 2,
'')
print @definition --you can now search this without false positives from comments.



Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1027086
Posted Monday, November 29, 2010 6:05 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, March 29, 2012 2:34 AM
Points: 4, Visits: 18
Hi

This really helps a lot - can build up list of all objects referencing the table then run through this.

Much appreciated

Many Thanks
Ralph
Post #1027276
Posted Monday, November 29, 2010 7:52 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Saturday, October 18, 2014 11:57 PM
Points: 78, Visits: 1,013
You could also use this free utility application to search SQL code while optionally ignoring comments, and/or to script out selected SQL routines in correct dependency order...

http://www.DBGizmo.net



Post #1027707
Posted Friday, July 15, 2011 5:53 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, March 6, 2012 12:02 PM
Points: 3, Visits: 53
Lowell (11/28/2010)
I have this snippets saved which might help; it's using a pair of loops table to strip out any comments , so you can then search just the remaining proc definition;
declare @definition varchar(max),
@objectname varchar(255),
@vbCrLf CHAR(2)
SET @vbCrLf = CHAR(13) + CHAR(10)

SET @objectname = 'sp_getDDL'
select @definition = definition + 'GO' + @vbcrlf from sys.sql_modules where [object_id] = object_id(@objectname)
--'objective: strip out comments.
--first loop is going to look for pairs of '/*' and '*/', and STUFF them with empty space.
--second loop is going to look for sets of '--' and vbCrLf and STUFF them with empty space.
--===== Replace all '/*' and '*/' pairs with nothing
WHILE CHARINDEX('/*',@definition) > 0
SELECT @definition = STUFF(@definition,
CHARINDEX('/*',@definition),
CHARINDEX('*/',@definition) - CHARINDEX('/*',@definition) + 2, --2 is the length of the search term
'')
--===== Replace all single line comments
WHILE CHARINDEX('--',@definition) > 0
AND CHARINDEX(@vbCrLf,@definition,CHARINDEX('--',@definition)) > CHARINDEX('--',@definition)
SELECT @definition = STUFF(@definition,
CHARINDEX('--',@definition),
CHARINDEX(@vbCrLf,@definition,CHARINDEX('--',@definition)) - CHARINDEX('--',@definition) + 2,
'')
print @definition --you can now search this without false positives from comments.



That rocks! I used that...
Post #1142872
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse