Find Text in All Databases

  • Comments posted to this topic are about the item Find Text in All Databases

    ----------------------------------------------------------01010011010100010100110000100000010100110110010101110010011101100110010101110010001000000101001001101111011000110110101101110011

  • hawg - Thursday, January 26, 2017 10:22 AM

    Comments posted to this topic are about the item Find Text in All Databases

    Very nice.  Any way to add the schema name of the objects found?

  • gvoshol 73146 - Monday, January 30, 2017 5:45 AM

    hawg - Thursday, January 26, 2017 10:22 AM

    Comments posted to this topic are about the item Find Text in All Databases

    Very nice.  Any way to add the schema name of the objects found?

    I have re-submitted an updated script that includes the schema in the results.  I will post another entry once the update gets published.

    ----------------------------------------------------------01010011010100010100110000100000010100110110010101110010011101100110010101110010001000000101001001101111011000110110101101110011

  • For this kind of occasional search it is reasonable to kind of ignore performance. This is not the kind of thing we do regularly. The concern for me is that sp_MSforeachdb will sometimes skip databases. This can cause all sorts of problems. Here are a couple of posts for alternatives to the undocumented and occasionally failing MS version.

    https://spaghettidba.com/2011/09/09/a-better-sp_msforeachdb/
    http://sqlblog.com/blogs/aaron_bertrand/archive/2010/12/29/a-more-reliable-and-more-flexible-sp-msforeachdb.aspx

    And since this only searching the definition of objects I would suggest that using SQL Search from Redgate (this forum's sponsor) is a better option. It is a free SSMS plugin that works fabulously for this type of thing. You can it here. http://www.red-gate.com/products/sql-development/sql-search/

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • gvoshol 73146, the script has now been updated to include the schema in the output.

    Sean Lange, I have heard about some problems with this undocumented procedure but I have  never experienced them so I have to leave those discussions to those that have.  I also agree that the Red Gate product is a good product but this script is useful when you don't have access to a tool such as Red Gate.

    ----------------------------------------------------------01010011010100010100110000100000010100110110010101110010011101100110010101110010001000000101001001101111011000110110101101110011

  • hawg - Monday, January 30, 2017 10:05 AM

    gvoshol 73146, the script has now been updated to include the schema in the output.

    Sean Lange, I have heard about some problems with this undocumented procedure but I have  never experienced them so I have to leave those discussions to those that have.  I also agree that the Red Gate product is a good product but this script is useful when you don't have access to a tool such as Red Gate.

    The RedGate tool is free so having access isn't really much of an issue. I point it out because many people have not heard of that issue and using an approach like described here leaves a person not realizing a database might have been skipped.

    For the sake of completeness here is a working example of another approach to this type of search that I have in my examples. I modified my version to return the same columns as your fine example. By no means am I being critical of your fine post. Instead I am pointing out an often missed issue with the undocumented sp_MSforeachdb. I used to use that for things like this until it once missed a database and as such my results were incorrect. I decided at that point it was time to find alternative methods. Here is one such approach.


    declare @search_string varchar(100) = 'mytext'
    declare @sql nvarchar(max) = '' --need to set this to an empty string for the next statement to work correctly

    select @sql = @sql + 'select DISTINCT ''' + db.name + ''' as DatabaseName, s.name AS Schema_Name, o.name AS Object_Name, o.type_desc
    FROM ' + db.name + '.sys.sql_modules m
    INNER JOIN ' + db.name + '.sys.objects o ON m.object_id = o.object_id
    INNER JOIN ' + db.name + '.sys.schemas s ON o.schema_id = s.schema_id
    WHERE m.definition Like ''%' + @search_string + '%'' UNION ALL
    '
    from sys.databases db
    where db.database_id > 4 --eliminates master, tempdb, model, msdb

    select @sql = STUFF(@sql, len(@sql) - 11, 11, '')

    select @sql
    --exec sp_executesql @sql --once you are comfortable with the dynamic sql you can uncomment this line

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Sean Lange, no worries!  I don't take any offense at a good conversation on here.  We're all here to learn, no matter how long we've been doing this.  Actually, the more I know, the more I realize I don't know.

    ----------------------------------------------------------01010011010100010100110000100000010100110110010101110010011101100110010101110010001000000101001001101111011000110110101101110011

  • hawg - Monday, January 30, 2017 1:24 PM

    Sean Lange, no worries!  I don't take any offense at a good conversation on here.  We're all here to learn, no matter how long we've been doing this.  Actually, the more I know, the more I realize I don't know.

    That gets more and more true each day. Glad you aren't taking offense because none is intended. Just sharing another approach to what can be a challenging piece of query to write.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Sean Lange:
    > The RedGate tool is free so having access isn't really much of an issue.
    I'm glad you posted code for an alternate method, because 3rd party tools can be an issue. Most companies prohibit downloading and installing software onto company-owned equipment.

Viewing 9 posts - 1 through 8 (of 8 total)

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