SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


search and replace a string in all user tables’ data in all databases


search and replace a string in all user tables’ data in all databases

Author
Message
Parag B
Parag B
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 51
Comments posted to this topic are about the item search and replace a string in all user tables’ data in all databases
a.grigoriu
a.grigoriu
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 50
Hi,
Nice SP.
Thank you.
It seems that it does not handle very well the schema names other than dbo.
Ex.
Invalid object name 'AdventureWorks.dbo.Location'.
Msg 208, Level 16, State 1, Line 1
The 'Location' table has 'Production' as schema and not 'dbo'

Cheers,
A.
Parag B
Parag B
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 51
Thanks for pointing out this..:-)
I have made some changes in the script to handle this. Please check out the modified script..

ALTER PROCEDURE [dbo].[usp_ReplaceString]
(
@FindString varchar(100),
@ReplaceString varchar(100)
)
AS

BEGIN

SET NOCOUNT ON


CREATE TABLE #FilteredTables(DatabaseID int,DatabaseName varchar(255),SchemaName varchar(255), TableName varchar(255),ColumnName varchar(128))
CREATE TABLE #AllDbTables(DatabaseID int,DatabaseName varchar(255),SchemaName varchar(255),TableName varchar(255),TableId int)
CREATE TABLE #AllDbTableColumns(DatabaseID int,DatabaseName varchar(255),SchemaName varchar(255),TableName varchar(255),ColumnName varchar(128))

DECLARE @DatabaseName nvarchar(255),@DatabaseID int,@TableName nvarchar(255), @ColumnName nvarchar(128),@cmd nvarchar(4000),@ErrorMsg varchar(4000),
@WhrFindString varchar(100),@TableId int,@Id int, @SchemaName varchar(255)

SET @WhrFindString = QUOTENAME('%' + @FindString + '%','''')

SET @cmd = ''
SET @Id = 0

-- Get tables from all the databases
DECLARE cur_Databases CURSOR FOR
SELECT QUOTENAME(name),database_id FROM sys.databases where name not in ('master','tempdb','model','msdb','ReportServer','ReportServerTempDB')
OPEN cur_Databases
FETCH NEXT FROM cur_Databases INTO @DatabaseName,@DatabaseID
WHILE (@@FETCH_STATUS = 0)
BEGIN

SET @cmd = 'insert into #AllDbTables select '''+cast(@DatabaseID as varchar)+''','''+@DatabaseName+''', QUOTENAME(SCHEMA_NAME(schema_id)), QUOTENAME(name)as TableName, object_id as TableID from '+@DatabaseName+'.sys.objects where type = ''u'' and is_ms_shipped = 0'
EXEC(@cmd)

FETCH NEXT FROM cur_Databases into @DatabaseName,@DatabaseID

END
CLOSE cur_Databases
DEALLOCATE cur_Databases

--Get columns for tables from all databases
DECLARE cur_Columns CURSOR FOR
SELECT DatabaseId,DatabaseName,SchemaName, TableName,TableID FROM #AllDbTables
OPEN cur_Columns
FETCH NEXT FROM cur_Columns INTO @DatabaseId,@DatabaseName,@SchemaName, @TableName,@TableID
WHILE (@@FETCH_STATUS = 0)
BEGIN
set @cmd = 'insert into #AllDbTableColumns select '''+cast(@DatabaseId as varchar)+''','''+@DatabaseName+''','''+@SchemaName+''','''+@TableName+''',QUOTENAME(name) FROM '+@DatabaseName+'.sys.columns WHERE object_id = '+cast(@TableID as varchar)+' AND system_type_id IN (167, 175, 231, 239, 35)'

exec(@cmd)
FETCH NEXT FROM cur_Columns INTO @DatabaseId,@DatabaseName,@SchemaName, @TableName,@TableID
end
CLOSE cur_Columns
DEALLOCATE cur_Columns

--Get table columns for only the String match
DECLARE cur_Filtered CURSOR FOR
SELECT DatabaseId,DatabaseName,SchemaName, TableName,ColumnName FROM #AllDbTableColumns
OPEN cur_Filtered
FETCH NEXT FROM cur_Filtered INTO @DatabaseId,@DatabaseName,@SchemaName, @TableName,@ColumnName
WHILE (@@FETCH_STATUS = 0)
BEGIN

-- Get only those tables and the particular column for which the match has found and inserts these details in temp table.
SET @cmd = 'IF EXISTS (SELECT * FROM '+ @DatabaseName+'.'+@SchemaName+'.'+@TableName + ' WHERE ' + @ColumnName + ' LIKE ''%' + @FindString + '%'') insert into #FilteredTables select '''+cast(@DatabaseId as varchar)+''','''+@DatabaseName+''',''' + @SchemaName+''','''+@TableName + ''', ''' + @ColumnName + ''''

EXEC(@cmd)

FETCH NEXT FROM cur_Filtered INTO @DatabaseId,@DatabaseName,@SchemaName, @TableName,@ColumnName

END
CLOSE cur_Filtered
DEALLOCATE cur_Filtered


SET @cmd = ''

IF EXISTS(SELECT * FROM #FilteredTables)
BEGIN

--- Cursor for creating update statement for the tables filtered above.
DECLARE cur_Replace CURSOR FOR
SELECT DatabaseId,DatabaseName,SchemaName, TableName,ColumnName FROM #FilteredTables
OPEN cur_Replace
FETCH NEXT FROM cur_Replace INTO @DatabaseId,@DatabaseName,@SchemaName, @TableName,@ColumnName
WHILE (@@FETCH_STATUS = 0)
BEGIN
SET @cmd = ' UPDATE ' + @SchemaName+'.'+@TableName +
' SET ' + @ColumnName
+ ' = REPLACE(' + @ColumnName + ', '
+ QUOTENAME(@FindString, '''') + ', ' + QUOTENAME(@ReplaceString, '''') +
') WHERE ' + @ColumnName + ' LIKE ' + @WhrFindString +CHAR(13)+';'

if(@Id != @DatabaseId)
begin

SET @cmd = 'USE '+@DatabaseName+';'+char(13)+@cmd+char(13)

end
PRINT @cmd


SET @Id = @DatabaseId
FETCH NEXT FROM cur_Replace INTO @DatabaseId,@DatabaseName,@SchemaName, @TableName,@ColumnName

END
CLOSE cur_Replace
DEALLOCATE cur_Replace

END
ELSE
BEGIN
PRINT 'No matche(s) Found for string '''+@FindString +''''
END


END
a.grigoriu
a.grigoriu
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 50
Hi,

I tested it, but it still does not match the right schema for the tables.
Ex:
Invalid object name 'AdventureWorks.develop.Department'.
Msg 208, Level 16, State 1, Line 1

The real schema for the table 'Department' in the 'AdventureWorks' DB is
'HumanResources':
[AdventureWorks].[HumanResources].[Department]

Maybe your script, in this version, is trying to inject the SP schema into resolving table names and not using the real schema for the tables. Just a wild guess... :-)

One more thing, may I suggest you to add as parameter the DB name?
Scanning a server instance with a lot of DB's is taking quite a while. Maybe you can use the null value for this param to indicate a full scan.

Nice job!

Cheers,
A.
UKGav
UKGav
SSC-Enthusiastic
SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)SSC-Enthusiastic (106 reputation)

Group: General Forum Members
Points: 106 Visits: 251
This looks very interesting (I've not tried it out myself as at time of writting), however isn't it RBAR using the cursor? Or rather DBAD ... Database By Agonising Database! Hehe

How long are people finding it takes to run on 2/3/5/10 databases?
Is there a SET based solution?

On a similar theme, if you want to search the SQL code within database objects, I can't recommend enough Redgate's SQL Search (tiny SSMS addon)...
http://www.red-gate.com/products/sql-development/sql-search/

Regards,
- Gavin
Parag B
Parag B
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 51
Thanks Gav B for the link..

Thats the great search tool. But I don't find any way or tool to replace the searched string with some other string , like I am doing in my script.

But as it is looping through all the databases ,it will be slow if the number of databases are large.
We can improve this by adding a parameter for Database, as suggested by A in the previous post.

Please let me know if you have any other views on this.

Thanks Smile
Parag B
Parag B
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 51
Hi a.grigoriu,

If you want to use the script for a single database, then create the below sp on that database and run.This will be a bit faster approach.

ALTER PROCEDURE [dbo].[usp_ReplaceStringForSingleDB]
(
@FindString varchar(100),
@ReplaceString varchar(100)
)
AS

BEGIN

SET NOCOUNT ON


CREATE TABLE #FilteredTables(SchemaName varchar(255),TableName varchar(255),ColumnName varchar(128))

DECLARE @SchemaName nvarchar(255), @TableName nvarchar(256), @ColumnName nvarchar(128),@cmd nvarchar(4000),@ErrorMsg varchar(4000),
@WhrFindString varchar(100),@TableId int
SET @TableName = ''


SET @WhrFindString = QUOTENAME('%' + @FindString + '%','''')

SET @cmd = 0


-- Get all user tables
DECLARE cur_Tables CURSOR FOR
SELECT QUOTENAME(Schema_name(schema_id)),QUOTENAME(name), object_id FROM sys.objects WHERE type = 'U' and is_ms_shipped = 0
OPEN cur_Tables
FETCH NEXT FROM cur_Tables INTO @SchemaName, @TableName, @TableId
WHILE (@@FETCH_STATUS = 0)
BEGIN

-- Get columns for table
DECLARE cur_Columns CURSOR FOR
SELECT QUOTENAME(name) FROM sys.columns WHERE object_id = @TableId AND system_type_id IN (167, 175, 231, 239, 99, 35)
OPEN cur_Columns
FETCH NEXT FROM cur_Columns INTO @ColumnName
WHILE (@@FETCH_STATUS = 0)
BEGIN

-- Get only those tables and the particular column for which the match has found and inserts these details in temp table.
SET @cmd = 'IF EXISTS (SELECT * FROM ' +@SchemaName+'.'+ @TableName + ' WHERE ' + @ColumnName + ' LIKE ''%' + @FindString + '%'') insert into #FilteredTables select ''' +@SchemaName+''','''+ @TableName + ''', ''' + @ColumnName + ''''

EXEC(@cmd)
--print @cmd

FETCH NEXT FROM cur_Columns INTO @ColumnName
END
CLOSE cur_Columns
DEALLOCATE cur_Columns


FETCH NEXT FROM cur_Tables INTO @SchemaName, @TableName, @TableId
END
CLOSE cur_Tables
DEALLOCATE cur_Tables

set @cmd = ''

--- Cursor for creating and runing update statements for the tables filtered above.
DECLARE cur_Replace CURSOR FOR
SELECT SchemaName, TableName,ColumnName FROM #FilteredTables
OPEN cur_Replace
FETCH NEXT FROM cur_Replace INTO @SchemaName, @TableName,@ColumnName
WHILE (@@FETCH_STATUS = 0)
BEGIN
SET @cmd = 'UPDATE ' + @SchemaName+'.'+@TableName +
' SET ' + @ColumnName
+ ' = REPLACE(' + @ColumnName + ', '
+ QUOTENAME(@FindString, '''') + ', ' + QUOTENAME(@ReplaceString, '''') +
') WHERE ' + @ColumnName + ' LIKE ' + @WhrFindString

print @cmd


FETCH NEXT FROM cur_Replace INTO @SchemaName, @TableName,@ColumnName
END
CLOSE cur_Replace
DEALLOCATE cur_Replace


END
a.grigoriu
a.grigoriu
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 50
Hi paragbhuyar02,

Thanks for the script.

Regards,
Adrian
Eric M Russell
Eric M Russell
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16486 Visits: 10947
I'm trying to think of a situation where I would want to replace a string value across X varchar columns in X tables and X databases. This would imply that someone needs to perform a quick and dirty update on a large database that they are not familiar with. However, I do like that it simply prints the UPDATE statements to the console rather than actually executing them.


"The universe is complicated and for the most part beyond your control, but your life is only as complicated as you choose it to be."
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search