http://www.sqlservercentral.com/blogs/kendalvandyke/2009/11/23/replication-scripts_3A00_-show-all-transactional-publications-_2600_-subscribers-at-distributor/

Printed 2014/10/01 05:22PM

Replication Scripts: Show All Transactional Publications & Subscribers At Distributor

By Kendal Van Dyke, 2009/11/23

Anybody who has talked with me about replication or heard me present about it knows that I recommend using a dedicated remote distributor for anything beyond light replication workloads. Unfortunately neither SSMS nor Replication Monitor provide an easy "one view to rule them all" way at the distributor (or anywhere else) to show every transactional publication, subscriber, and article they're subscribed to. The only way to gather that information using SSMS is to script out each publication and visually parse the scripts. I manage hundreds of publications & subscriptions and that's not a reasonable option for me so I've written this script to show me everything at once:

-- Show Transactional Publications and Subscriptions to articles at Distributor
-- Run this on the DISTRIBUTOR
-- Add a WHERE clause to limit results to one publisher\subscriber\publication\etc
SELECT  publishers.srvname AS [Publisher] ,
       
publications.publisher_db AS [Publisher DB] ,
       
publications.publication AS [Publication] ,
       
subscribers.srvname AS [Subscriber] ,
       
subscriptions.subscriber_db AS [Subscriber DB] ,
       
articles.article AS [Article]
FROM    sys.sysservers AS publishers
       
INNER JOIN distribution.dbo.MSarticles AS articles ON publishers.srvid = articles.publisher_id
       
INNER JOIN distribution.dbo.MSpublications AS publications ON articles.publisher_id = publications.publisher_id
                                                             
AND articles.publication_id = publications.publication_id
       
INNER JOIN distribution.dbo.MSsubscriptions AS subscriptions ON articles.publisher_id = subscriptions.publisher_id
                                                             
AND articles.publication_id = subscriptions.publication_id
                                                             
AND articles.article_id = subscriptions.article_id
       
INNER JOIN sys.sysservers AS subscribers ON subscriptions.subscriber_id = subscribers.srvid

-- Limit results to subscriber 
--WHERE   subscribers.srvname = '[Subscriber Server Name]'

---- Limit results to publisher and publication
--WHERE   publishers.srvname = '[Publisher Server Name]'
--        AND MSpublications.publication = '[Publication Name]'

ORDER BY publishers.srvname ,
       
subscribers.srvname ,
       
publications.publication ,
       
articles.article


This script also works for distributors running SQL 2000; just substitute master.dbo.sysservers in place of sys.sysservers.


Copyright © 2002-2014 Simple Talk Publishing. All Rights Reserved. Privacy Policy. Terms of Use. Report Abuse.