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

Searching Syscomments Accurately

By Robert Cary,

One of my biggest concerns when changing the database schema is how it will affect the applications. I am fortunate to work for a company that ensures all SQL code is encapsulated into stored procedures so searching for dependencies is fairly straightforward. We have a very nice tool, in fact, for doing just that.

Recently I was investigating a fairly volatile table to see how it was populated but, oddly, our search tool didn't show any procs that referenced that table; it turns out that there was a very subtle flaw.

Searching PROC/TRIGGER source code accurately

PROC/Trigger/etc source is stored in the syscomments table as an NVARCHAR(4000), when you have a PROC that exceeds 4000 characters, the source spans multiple rows. Very occasionally this-multi row split occurs right in the middle of the string you are searching for. To overcome this we need to concatenate the rows, returning the full string for each id (avoiding loops and cursors wherever practical).

SQL 2005 Solution

The query below will concatenate the text for each PROC/Trigger/etc (up to ~100,000 bytes long)

SELECT o.Name, o.Type
FROM
(
SELECT id,
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 1 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 2 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 3 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 4 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 5 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 6 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 7 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 8 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 9 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 10 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 11 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 12 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 13 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 14 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 15 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 16 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 17 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 18 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 19 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 20 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 21 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 22 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 23 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 24 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 25 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 26 THEN sc.text END), '') AS NVARCHAR(max)) +
 CAST(COALESCE(MIN(CASE WHEN sc.colId = 27 THEN sc.text END), '') AS NVARCHAR(max)) [text]
FROM syscomments SC
WHERE SC.colId IS NOT NULL
GROUP BY id
) C
INNER JOIN sysobjects O
ON C.id = O.id
WHERE C.text LIKE '%YourSearchString%'

Unfortunately, if you are not running 2005 the above code will fail as previous versions of SQL Server do not support the VARCHAR(MAX) type. Furthermore, a code change is required if you have very large procs (>100k)

If you don't mind a bit of dynamic SQL, you could re-code the above solution as follows:

DECLARE @searchStr VARCHAR(MAX)

SELECT @searchStr = COALESCE(@searchStr + ' + ', 'SELECT o.Name, o.Type ' 
	+ CHAR(13) + 'FROM (' + CHAR(13) + 'SELECT id, ' + CHAR(13) + ' ') 
	+  'CAST(COALESCE(MIN(CASE
WHEN sc.colId = 
  ' + CAST(ColID AS VARCHAR) + ' THEN sc.text END), '''') AS NVARCHAR(max))' 
  + CHAR(13)
 FROM Syscomments
 GROUP BY ColID
 order by colid

SET @searchStr = @searchStr + ' [text] ' + CHAR(13) + 'FROM syscomments SC'
	+ CHAR(13) + 'WHERE SC.colId IS NOT NULL' + CHAR(13) 
	+ 'GROUP BY id' + CHAR(13) + ') C' + CHAR(13) + 'INNER JOIN sysobjects O' 
	+ CHAR(13) + ' ON C.id = O.id'
	+ CHAR(13) + 'WHERE C.text LIKE ''%YourSearchString%'''

EXEC(@searchStr)

This results in a query that will be capable of searching stored procs of any size without requiring a code change.

SQL 2000 Solution

If you aren't yet running 2005, there are still a few options. The next query should run in most versions of SQL server (I haven't tested it though on anything other than 2000). Because you cannot concatenate and search the full source code, you have to break the search up. This code utilizes a numbers table (Num table article and source) to concatenate two rows at a time, converting the NVARCHAR(4000) to a VARCHAR(8000). This code allows you to search the row edges by concatenating row 1 & 2, 2 & 3, 3 & 4 and so on.

SELECT DISTINCT O.Name, O.Type
 FROM
 (
 SELECT Id,
  CAST(COALESCE(MIN(CASE WHEN sc.colId = Num-1 THEN sc.text END), '') AS VARCHAR(8000)) +
  CAST(COALESCE(MIN(CASE WHEN sc.colId = Num THEN sc.text END), '') AS VARCHAR(8000)) AS [text]
FROM syscomments SC
 INNER JOIN numbers N
 ON N.Num = SC.colid
 OR N.num-1 = SC.colid
WHERE N.Num < 30
 GROUP BY id, Num
) C
INNER JOIN sysobjects O
 ON C.id = O.Id
 WHERE C.TEXT LIKE '%YourSearchString%'
 

Performance

Of course, this is going to be an expensive query no matter how you slice it. Fortunately, it is very ad-hoc in nature. The 2000 code certainly looks more elegant, but running it in my dev environment (2005) returns the following I/O statistics

Table 'Worktable'. Scan count 4, logical reads 18778, physical reads 0
  , read-ahead reads 0, lob logical reads 0, lob physical reads 0
  , lob read-ahead reads 0.
Table 'Worktable'. Scan count 0, logical reads 0, physical reads 0
  , read-ahead reads 0, lob logical reads 0, lob physical reads 0
  , lob read-ahead reads 0.
Table 'Numbers'. Scan count 4, logical reads 8, physical reads 0
  , read-ahead reads 0, lob logical reads 0, lob physical reads 0
  , lob read-ahead reads 0.
Table 'sysobjvalues'. Scan count 1, logical reads 366, physical reads 0
  , read-ahead reads 0, lob logical reads 0, lob physical reads 0
  , lob read-ahead reads 0.
Table 'syscolpars'. Scan count 1, logical reads 91, physical reads 0
  , read-ahead reads 0, lob logical reads 0, lob physical reads 0
  , lob read-ahead reads 0.
Table 'sysschobjs'. Scan count 1, logical reads 32, physical reads 0
  , read-ahead reads 0, lob logical reads 0, lob physical reads 0
  , lob read-ahead reads 0.

That is a huge number of reads! At least compared to the 2005 solution shown below:

Table 'sysschobjs'. Scan count 1, logical reads 41, physical reads 0
  , read-ahead reads 0, lob logical reads 0, lob physical reads 0
  , lob read-ahead reads 0.
Table 'Worktable'. Scan count 0, logical reads 0, physical reads 0
  , read-ahead reads 0, lob logical reads 0, lob physical reads 0
  , lob read-ahead reads 0.
Table 'sysobjvalues'. Scan count 1, logical reads 366, physical reads 0
  , read-ahead reads 0, lob logical reads 0, lob physical reads 0
  , lob read-ahead reads 0.
Table 'syscolpars'. Scan count 1, logical reads 91, physical reads 0
  , read-ahead reads 0, lob logical reads 0, lob physical reads 0
  , lob read-ahead reads 0.

Conclusion

There are a number of ways to tackle this issue; this is my approach. I chose this approach, more than anything else, to see if it was possible. I would love to hear more (and better) ideas.

Total article views: 7896 | Views in the last 30 days: 12
 
Related Articles
FORUM

Coalesce on inner queries

Coalesce on inner queries

FORUM

Coalesce Query

Coalesce Query

FORUM

JOINS with COALESCE

JOINS with COALESCE

FORUM

nvarchar max problem

nvarchar max not fulfilling requirements

FORUM

Coalesce returning 1 value only

Afkas - Coalesce issue

Tags
 
Contribute

Join the most active online SQL Server Community

SQL knowledge, delivered daily, free:

Email address:  

You make SSC a better place

As a member of SQLServerCentral, you get free access to loads of fresh content: thousands of articles and SQL scripts, a library of free eBooks, a weekly database news roundup, a great Q & A platform… And it’s our huge, buzzing community of SQL Server Professionals that makes it such a success.

Join us!

Steve Jones
Editor, SQLServerCentral.com

Already a member? Jump in:

Email address:   Password:   Remember me: Forgotten your password?
Steve Jones