Searching Syscomments Accurately

  • Comments posted here are about the content posted at http://www.sqlservercentral.com/columnists/rcary/2792.asp

    SQL guy and Houston Magician

  • I have a solution that I use to find occurrences of a string within any stored procedure in a database. Although is uses a cursor, I have found the performance to be more than acceptable. This solution also has the merit of telling you the line number that the match was found on.

    CREATE proc dbo.zspFind

    @Search varchar(100)

    as

    DECLARE cur CURSOR

    READ_ONLY

    FOR select name, syscomments.id, colid

    from syscomments

    join sysobjects on syscomments.id=sysobjects.id

    where xtype='P' and category=0

    order by name, colid

    DECLARE @name varchar(100)

    DECLARE @id int

    DECLARE @colid int

    DECLARE @buf varchar(8000)

    DECLARE @pos1 int

    DECLARE @pos2 int

    DECLARE @line varchar(4000)

    DECLARE @lineno int

    declare @out table (Name varchar(100), line int, [text] varchar(1000))

    OPEN cur

    set @buf=''

    set @lineno=1

    FETCH NEXT FROM cur INTO @name, @id, @colid

    WHILE (@@fetch_status -1)

    BEGIN

    select @buf=@buf+cast([text] as varchar(4000)) from syscomments where id=@id and colid=@colid

    set @pos1=1

    select @pos2=charindex(char(10), @buf, @pos1)

    while @pos2>0

    begin

    select @line=substring(@buf, @pos1, @pos2-@pos1), @lineno=@lineno+1

    if charindex(@Search, @line)>0

    begin

    set @line =replace(@line, char(9), '')

    insert into @out values (@name, @lineno, @line)

    end

    select @pos1=@pos2+1

    select @pos2=charindex(char(10), @buf, @pos1)

    end

    set @buf=substring(@buf, @pos1, 4000)

    FETCH NEXT FROM cur INTO @name, @id, @colid

    if @colid=1 set @lineNo=1

    END

    CLOSE cur

    DEALLOCATE cur

    select * from @out

  • Nice article

    The solution I use is to populate a table overnight with the full syscomments text for each object, across multiple databases.  This table can then be queried.  We use an Access front-end for the querying, so we can return a list of matches and then drilldown for a further look into the full text.

    An addition I'd like to make is to highlight the search string in the objects, like Google does with search results.  I do like the idea of the line numbering mentioned above too.

  • Nice work. I knew a proc could get split across multiple rows, just never ran into the scenario you describe where the word is split (or I ran into and didnt notice it!). Creating the super select as a view might come in handy.

  • I haven't tried it for this scenario, but I would think that you could call the new 2005 function OBJECT_DEFINITION on the sysobjects table, and then query that function to find the dependencies that you are looking for. OBJECT_DEFINITION returns a varchar(max), so it is searchable.

    SELECT name FROM sys.objects

    WHERE OBJECT_DEFINITION(object_id) LIKE '%searchtext%'

  • I usually know the whereabouts of the code I'm searching for, but if I really had to find something in the code, I'd probably script everything to a file and search for the string with a regular expressions enabled text editor since I would probably anyway have problems finding words with white space and/or line breaks between them.

  • If you are using an access front end, you can use the rich text box control to display the text and highlight the results. I implemented a similar thing years ago. If you really want it to fly, you can edit the raw RTF, but the performance is just as acceptable using the built in methods of the control.

    SQL guy and Houston Magician

  • OBJECT_DEFINITION sounds like a real winner! I hadn't heard of that function, it sounds perfect though!

    Thanks for sharing this tip Tim! I guess I need to swot up some more on SQL 2005!

    SQL guy and Houston Magician

  • That's definitly a valid approach, and I like that your solution give you line numbers. I have often wanted to expand out the functionality of my search app to be more like grep. It would be great to be able to see the line(s) the string appears on, so you have the context, line numbers etc.

    SQL guy and Houston Magician

  • If you're using SQL Server 2005, wouldn't you do better to search sys.sql_modules?  That's the replacement for syscomments.  The definition column holds all the sql definitions, and is nvarchar(max).

    I imagine the object_definition() function simply queries that view, so you should get better performance by searching the view directly rather than using the function.

  • Maybe...but its probably negligible. If you use sys.sql_modules, you still have to go lookup the name of the object.

    Tim

  • Thank you to everyone who has commented on the article. I've really enjoyed hearing how others have approached this problem and it's also great to hear that there are better approaches available in SQL2k. I've learned a lot from you guys!

    SQL guy and Houston Magician

  • Robert,

    Your solution works great ... I am however having a bit of a problem following the code - could you clarify the significance of the number 30 used in the WHERE clause?

     

    Thanks a lot

  • The 30 is an arbitary max of colid. If you have a proc greater than 120,000 bytes long, this will fail. Thank you for brining this up.

    I've thought about it and there are three options:

    1. Lookup the max colid value from syscomments before running the query (although this seems to kill the query plan)

    2. Use the maximum possible value (255)

    3. Skip the numbers table and join syscomments to itself to generate your range of colId Values.

    Here is the code:

    DECLARE @max SMALLINT
    SELECT @max = max(COlid) FROM syscomments 
    
    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 <= @max
            GROUP BY id, Num
        ) C
    INNER JOIN sysobjects O
        ON C.id = O.Id
    WHERE C.TEXT LIKE '%yourSearchString%'
     
    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 <= 255
            GROUP BY id, Num
        ) C
    INNER JOIN sysobjects O
        ON C.id = O.Id
    WHERE C.TEXT LIKE '%yourSearchString%'
    
    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 (SELECT TOP 100 PERCENT ColID AS Num FROM Syscomments GROUP BY ColID ORDER BY ColID DESC) N
     ON N.Num = SC.colid
     OR N.num-1 = SC.colid
     GROUP BY id, Num
    ) C
    INNER JOIN sysobjects O
     ON C.id = O.Id
     WHERE C.TEXT LIKE '%yourSearchString%'
    

    Overall, the last query--with the self-join--appears to be the fastest; it has fewer scans but more reads.

    I hope this all helps

    SQL guy and Houston Magician

  • This is also a good solution from Tim Chapman. He is using object_definition() function.

    http://www.sqlservercentral.com/articles/articlelink.asp?articleid=2809

    Andy

Viewing 15 posts - 1 through 15 (of 24 total)

You must be logged in to reply to this topic. Login to reply