SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 General SQL Server Forums
 Script Library
 Searching Procedure Text
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

robvolk
Most Valuable Yak

USA
15681 Posts

Posted - 02/05/2004 :  20:07:41  Show Profile  Visit robvolk's Homepage  Reply with Quote
Everyone seems to think this needs something elaborate:

CREATE PROCEDURE sp_FindText @text varchar(8000), @findtype varchar(1)='P' AS
SET NOCOUNT ON
IF @findtype='P' SELECT DISTINCT Len(SubString(text,1, PatIndex('%' + @text + '%', text)))-Len(Replace(SubString(text,1, PatIndex('%' + @text + '%', text)),char(13),''))+1 AS Line,
--PatIndex('%' + @text + '%', text) AS Position,
OBJECT_NAME(id) AS ProcName
FROM syscomments
WHERE text like '%' + @text + '%'
ORDER BY ProcName, Line

IF @findtype='C' EXEC('SELECT TABLE_NAME + ''.'' + COLUMN_NAME AS TableColumn FROM INFORMATION_SCHEMA.COLUMNS WHERE COLUMN_NAME LIKE ''%' + @text + '%'' ORDER BY TableColumn')

IF @findtype='T' EXEC('SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME LIKE ''%' + @text + '%'' ORDER BY TABLE_NAME')
GO


It not only searches procedure and view definition text, it will also find tables, views, and column names:

EXEC sp_FindText 'myTable' --or-- EXEC sp_FindText 'myTable', 'P' --finds procedures/views containing 'myTable' in their definition/code
EXEC sp_FindText 'myTable', 'T' --finds tables/views containing 'myTable' in their name
EXEC sp_FindText 'myCol', 'C' --finds columns containing 'myCol' in their name

It's pretty easy to modify and extend, and probably doesn't need dynamic SQL either. It returns line numbers for views and procedures, but these can be incorrect if the procedure or view contains over 4000 characters of code. It does not search tables for values, it's strictly for finding object names.

tkizer
Almighty SQL Goddess

USA
37287 Posts

Posted - 02/05/2004 :  20:09:24  Show Profile  Visit tkizer's Homepage  Reply with Quote
Very cool, Rob. I'll have to compare Vyas' with yours.

Tara
Go to Top of Page

X002548
Not Just a Number

15586 Posts

Posted - 02/06/2004 :  11:09:38  Show Profile  Reply with Quote
See, I break out the sledge hammer and Rob uses a scalpel...

very nice....

I could go in and try to figure it out...but how do you derive line?

oops...never mind,,,it's the old length - length replace thing up to the location of the search arg...

did I say very nice....



Brett

8-)
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.06 seconds. Powered By: Snitz Forums 2000