Technical Article

Synchronize a view between two servers

,

This script is the same method with spSynchStoredProcedure but used for views.

To run this stored procedure, you need to create two linked servers for your source server and your target server. You can create them in local SQL Server and then run this to synchronize.

For example, your development server is called DEV and your production server is called PROD, and you create two linked servers in local SQL Server with the same name. Assumed that your database between DEV and PROD have the same name: TestDB.

If you want to synchronize a view called TestView between TestDB of DEV and PROD, you can excute like that:

EXEC dbo.spSynchView @ViewName = 'TestView', @SourceServer = 'DEV', @SourceDatabase = 'TestDB', @TargetServer = 'PROD', @TargetDatabase = 'TestDB'

This procedure may be useful if your view is not over 4000 characters. If it's over 4000 characters, you have to modify it a little.

CREATE PROCEDURE [dbo].[spSynchView]
@ViewName VARCHAR(50) = NULL,
@SourceServer VARCHAR(50) = NULL,
@SourceDatabase VARCHAR(50) = NULL,
@TargetServer VARCHAR(50) = NULL,
@TargetDatabase VARCHAR(50) = NULL
AS
BEGIN
SET NOCOUNT ON;
DECLARE @STRSQL NVARCHAR(MAX);
DECLARE @Params NVARCHAR(MAX);
DECLARE @IsExisted BIT;
DECLARE @ViewSource NVARCHAR(MAX);
SET @IsExisted = 0;
SET @STRSQL = N' SELECT @IsExisted = 1
FROM ' + @TargetServer + '.' + @TargetDatabase + '.sys.objects
WHERE name = ''' + @ViewName + ''' AND Type = ''V''';
SET @Params = N'@IsExisted BIT OUTPUT';
EXEC sp_executesql @STRSQL, @Params, @IsExisted = @IsExisted OUTPUT
IF (@IsExisted = 1)
BEGIN
SET @STRSQL = N'EXEC ' + @TargetServer + '.' + @TargetDatabase + 'dbo.sp_executesql N''DROP VIEW ' + @ViewName + '''';
EXECUTE(@STRSQL);
END;

SET @STRSQL = N'SELECT @ViewSource = t1.text 
FROM ' + @SourceServer + '.' + @SourceDatabase + '.dbo.syscomments t1
INNER JOIN ' + @SourceServer + '.' + @SourceDatabase + '.dbo.sysobjects t2 on t1.id = t2.id
WHERE t2.xtype = ''V''
AND t2.name = ''' + @ViewName + '''';
SET @Params = N'@ViewSource NVARCHAR(MAX) OUTPUT'
EXEC sp_executesql @STRSQL, @Params, @ViewSource = @ViewSource OUTPUT

SET @ViewSource = REPLACE(@ViewSource, '''', '''''');
SET @STRSQL = N'EXEC ' + @TargetServer + '.' + @TargetDatabase + '.dbo.sp_executesql N''' + @ViewSource + '''';
--PRINT @ViewSource;
--PRINT @STRSQL;
EXECUTE(@STRSQL);
END

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating