February 1, 2008 at 8:20 am
Comments posted to this topic are about the item Find a text string in any column in a database.
Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]
February 8, 2008 at 6:13 am
Nice script.
A couple of questions for you:
- Shouldn't there be a set of [ ] around the variables in case they contain special characters like blanks or SQL keywords?
- How can you handle special characters in the LIKE comparison if a string you would search for has a %, _, [ ], [^ ] or quotes?
Toni
February 8, 2008 at 6:37 am
toniupstny (2/8/2008)
Nice script.A couple of questions for you:
- Shouldn't there be a set of [ ] around the variables in case they contain special characters like blanks or SQL keywords?
- How can you handle special characters in the LIKE comparison if a string you would search for has a %, _, [ ], [^ ] or quotes?
I agree. It failed immediately for me for a column named "Group".
SET @Sql = 'SELECT @Row_Count = COUNT(*) '+
' FROM ' + @Table_Name + ' (NOLOCK) WHERE [' + @Column_Name + '] LIKE ''%' + @Search_For + '%'''
Adding the brackets prevents the ambiguity of the word.
Given that, I see this as a useful time-saver when a word or phrase may have been used in numerous places.
Thanks!
February 8, 2008 at 7:13 am
Fair point. I'll have to make the change. The times that I used it I wasn't looking for anything with special characters or keywords.
Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]
February 8, 2008 at 7:37 am
toniupstny (2/8/2008)
Nice script.A couple of questions for you:
- Shouldn't there be a set of [ ] around the variables in case they contain special characters like blanks or SQL keywords?
- How can you handle special characters in the LIKE comparison if a string you would search for has a %, _, [ ], [^ ] or quotes?
Toni
I've now added the []'s around the table_name and column_name. I'm not sure when the update will be posted but its a fairly simple change.
Change this line
' FROM ' + @Table_Name + ' (NOLOCK) WHERE ' + @Column_Name + ' LIKE ''%' + @Search_For + '%'''
To this line
' FROM [' + @Table_Name + '] (NOLOCK) WHERE [' + @Column_Name + '] LIKE ''%' + @Search_For + '%'''
As far as pattern searching goes if you want to search on a pattern matching character put it in []'s. So for example if you want to search for the literal string 'test%' you would put it as 'test[%]'.
I thought about putting it in code but then you couldn't add extra patterns. For example as it stands you can search on the word 'test' with a single digit number after it by making the search string 'test[0-9]'
Kenneth
Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]
February 12, 2008 at 4:48 am
I admit my SQL knowledge is extremely limited, but am I missing something very basic here? All I get is an Error 208 - Invalid Object Name INFORMATION_SCHEMA.Tables. It would appear that these views only exist in and relate to the master database on our system. All of our other databases, setup by applications such as a Sage ERP system, Backup Exec, etc., have no such views.
February 12, 2008 at 8:04 am
They are system views. They do only exist in Master but everyone should have access to them and they can be used from any database. Just like the system stored procedures. I'm honestly not sure why you can't use them normally. If you want I can re-write it to work on the base system tables.
Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]
February 12, 2008 at 9:20 am
Actually the answer was quite simple: quite why I am not sure, but on our system all these objects are defined with upper case names and have to be referenced as such, e.g. "INNER JOIN INFORMATION_SCHEMA.TABLES Tables ON Columns.TABLE_NAME = Tables.TABLE_NAME". Many Thanks.
February 12, 2008 at 9:25 am
Actually I'll bet you have your default collation set to be case sensative. On all of the systems I have run it on the server has been case in-sesative so I didn't have any problems.
Hope you find the script helpful π
Kenneth
Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]
May 18, 2012 at 9:45 am
How do you see the results?. When I execute the script I get a bunch of '(1 row(s) affected'. Thanks for your assistance.
May 18, 2012 at 2:27 pm
If you are using "results to text" the output will be between the 3rd and 4th "(1 row(s) affected)" .
I'm adding a SET NOCOUNT ON to the top of the script in order to turn off the extra output.
You probably arn't getting any results. If you switch to "results to grid" you will get your results seperate from the text output.
Kenneth
Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]
February 22, 2013 at 2:57 am
Thank you. Very useful and simple.
May 10, 2016 at 1:45 pm
Thanks for the script.
March 31, 2022 at 11:42 am
I know it's been years since this post was made and the script still works great.
I just added the TABLE_SCHEMA to make thing run a bit better on my db that has many different schema's. No other changes was made.
SET NOCOUNT ON
DECLARE @Search_For varchar(4000)
DECLARE @Table_Name varchar(255)
DECLARE @Schema_Name varchar(255)
DECLARE @Column_Name varchar(255)
DECLARE @Row_Count int
DECLARE @Sql nvarchar(4000)
DECLARE @Results Table
ββββ(
ββββTable_Name varchar(255),
ββββColumn_Name varchar(255),
ββββRow_Count int
ββββ)
DECLARE Field_List CURSOR FOR
ββββSELECT COLUMNS.Table_Name, COLUMNS.TABLE_SCHEMA, COLUMNS.Column_Name
ββββFROM INFORMATION_SCHEMA.COLUMNS COLUMNS
ββββINNER JOIN INFORMATION_SCHEMA.TABLES TABLES ON COLUMNS.Table_Name = TABLES.Table_Name
ββββWHERE COLUMNS.Data_Type IN ('char','varchar','nchar','nvarchar','text','ntext')
ββββ AND TABLES.Table_Type = 'Base Table'
----------------------------------
SET @Search_For = '051021.upd'
----------------------------------
OPEN Field_List
FETCH NEXT FROM Field_List INTO @Table_Name, @Schema_Name, @Column_Name
WHILE (@@fetch_status <> -1)
BEGIN
ββββIF (@@fetch_status <> -2)
ββββBEGIN
ββββββββ-- Generate & run dynamic SQL
ββββββββSET @Sql = 'SELECT @Row_Count = COUNT(*) '+
ββββββββββββ' FROM [' + @Schema_Name + '].[' + @Table_Name + '] (NOLOCK) WHERE [' + @Column_Name + '] LIKE ''%' + @Search_For + '%'''
ββββββββEXEC sp_ExecuteSql @Sql, N'@Row_Count Int OUTPUT', @Row_Count OUTPUT
ββββββββIF @@Error <> 0
ββββββββPRINT @Sql
ββββββββ-- Store results
ββββββββIF @Row_Count > 0
ββββββββββββINSERT INTO @Results VALUES (@Table_Name, @Column_Name, @Row_Count)
ββββEND
ββββFETCH NEXT FROM Field_List INTO @Table_Name, @Schema_Name, @Column_Name
END
CLOSE Field_List
DEALLOCATE Field_List
SELECT * FROM @Results
GO
Viewing 14 posts - 1 through 13 (of 13 total)
You must be logged in to reply to this topic. Login to reply