Saturday 25 February 2012

A Script A Day - Day 19 - Remove Virtual Subscriptions

Today’s script is to help replication performance.  It was something I learned from my resident replication expert Paul Anderton.  Below is a description of virtual subscriptions.

If Immediate_Sync is set when a publication is created then virtual subscriptions can occur.  These can affect the "Distribution Clean Up: distribution" SQL job and the "msrepl_commands" table.  By Default the job runs every 10 mins and removes replicated commands from the "msrepl_commands" table dependant on the @min_distretention value (0 hrs is default).  If virtual subscriptions are present then the @min_distretention value is ignored and all replicated commands will only be removed after the @max_distretention is reached (72 hrs is default).

This script is one I have run on all my servers serving as a distributor to remove the virtual subscribers.  The performance gain in all instances is fantastic the distribution clean up job runs a lot faster and replication latency (number of undistributed commands) is dramatically reduced.

/*
      -----------------------------------------------------------------
      Remove Virtual Subscriptions
      -----------------------------------------------------------------
     
      For more SQL resources, check out SQLServer365.blogspot.co.uk

      -----------------------------------------------------------------

      You may alter this code for your own purposes.
      You may republish altered code as long as you give due credit.
      You must obtain prior permission before blogging this code.
 
      THIS CODE AND INFORMATION ARE PROVIDED "AS IS"
     
      -----------------------------------------------------------------
*/
-- Set database context
USE distribution;
GO
-- Get undelivered commands
SELECT
      *
FROM
      MSdistribution_status
ORDER BY
      UndelivCmdsInDistDB DESC

-- Check for virtual subscriptions
SELECT
      msp.publication,
      mss.publisher_db,
      mss.publication_id,
      mss.subscriber_id,
      mss.subscriber_db,
      mss.subscription_type,
      mss.[status]
FROM
      distribution.dbo.MSsubscriptions mss
      left join distribution.dbo.MSpublications msp ON mss.publication_id = msp.publication_id
GROUP BY
      msp.publication,
      mss.publisher_db,
      mss.publication_id,
      mss.subscriber_id,
      mss.subscriber_db,
      mss.subscription_type,
      mss.[status];
GO

-- Remove virtual subscriptions
DECLARE @minid INT
DECLARE     @maxid INT
DECLARE @pubname VARCHAR(100)
DECLARE     @pubdb VARCHAR(100)

SELECT
      @minid = MIN(mss.publication_id),
      @maxid =  MAX(mss.publication_id)
FROM
      distribution.dbo.MSsubscriptions mss
      INNER JOIN distribution.dbo.MSpublications msp ON mss.publication_id = msp.publication_id
WHERE
      mss.subscriber_db = 'virtual'

WHILE @minid <= @maxid
BEGIN
      SELECT
            @pubname = msp.publication,
            @pubdb = mss.publisher_db
      FROM
            distribution.dbo.MSsubscriptions mss
      INNER JOIN distribution.dbo.MSpublications msp ON mss.publication_id = msp.publication_id
      WHERE
            mss.subscriber_db = 'virtual'
            AND mss.publication_id = @minid
           
                        EXEC ('
                        EXEC ' + @pubdb + '.dbo.sp_changepublication
                        @publication = ' + @pubname + ',
                        @property = ''allow_anonymous'',
                        @value = ''false'' ;
                        ')

                        EXEC ('
                        EXEC ' + @pubdb + '.dbo.sp_changepublication
                        @publication = ' + @pubname + ',
                        @property = ''immediate_sync'',
                        @value = ''false'' ;
                        ')

SELECT
      @minid = MIN(mss.publication_id)
FROM
      distribution.dbo.MSsubscriptions mss
      inner join distribution.dbo.MSpublications msp ON mss.publication_id = msp.publication_id
WHERE
      mss.subscriber_db = 'virtual'
      AND mss.publication_id > @minid
END;
GO

-- Check for virtual subscriptions
SELECT
      msp.publication,
      mss.publisher_db,
      mss.publication_id,
      mss.subscriber_id,
      mss.subscriber_db,
      mss.subscription_type,
      mss.[status]
FROM
      distribution.dbo.MSsubscriptions mss
      left join distribution.dbo.MSpublications msp ON mss.publication_id = msp.publication_id
GROUP BY
      msp.publication,
      mss.publisher_db,
      mss.publication_id,
      mss.subscriber_id,
      mss.subscriber_db,
      mss.subscription_type,
      mss.[status];
GO

Enjoy!

Chris

No comments:

Post a Comment