locked
Push and Pull Transaction Replication RRS feed

  • Question

  • How do we know if the current replication is PUSH or PULL and where the distributor database is at Publisher or Subscriber?

    Thanks,

    Wednesday, February 26, 2014 12:56 PM

Answers

  • Try the below:

    --First you find the distributor servername using the below running in publisher
    Use master
    EXEC sp_helpdistributor;
    
    --Then you can run the below to find the type (use distributor database)
    
    SELECT 
    (CASE  
        WHEN mdh.runstatus =  '1' THEN 'Start - '+cast(mdh.runstatus as varchar)
        WHEN mdh.runstatus =  '2' THEN 'Succeed - '+cast(mdh.runstatus as varchar)
        WHEN mdh.runstatus =  '3' THEN 'InProgress - '+cast(mdh.runstatus as varchar)
        WHEN mdh.runstatus =  '4' THEN 'Idle - '+cast(mdh.runstatus as varchar)
        WHEN mdh.runstatus =  '5' THEN 'Retry - '+cast(mdh.runstatus as varchar)
        WHEN mdh.runstatus =  '6' THEN 'Fail - '+cast(mdh.runstatus as varchar)
        ELSE CAST(mdh.runstatus AS VARCHAR)
    END) [Run Status], 
    mda.subscriber_db [Subscriber DB], 
    mda.publication [PUB Name],
    CONVERT(VARCHAR(25),mdh.[time]) [LastSynchronized],
    und.UndelivCmdsInDistDB [UndistCom], 
    mdh.comments [Comments], 
    'select * from distribution.dbo.msrepl_errors (nolock) where id = ' + CAST(mdh.error_id AS VARCHAR(8)) [Query More Info],
    mdh.xact_seqno [SEQ_NO],
    (CASE  
        WHEN mda.subscription_type =  '0' THEN 'Push' 
        WHEN mda.subscription_type =  '1' THEN 'Pull' 
        WHEN mda.subscription_type =  '2' THEN 'Anonymous' 
        ELSE CAST(mda.subscription_type AS VARCHAR)
    END) [SUB Type],
    
    mda.publisher_db+' - '+CAST(mda.publisher_database_id as varchar) [Publisher DB],
    mda.name [Pub - DB - Publication - SUB - AgentID]
    FROM distribution.dbo.MSdistribution_agents mda 
    LEFT JOIN distribution.dbo.MSdistribution_history mdh ON mdh.agent_id = mda.id 
    JOIN 
        (SELECT s.agent_id, MaxAgentValue.[time], SUM(CASE WHEN xact_seqno > MaxAgentValue.maxseq THEN 1 ELSE 0 END) AS UndelivCmdsInDistDB 
        FROM distribution.dbo.MSrepl_commands t (NOLOCK)  
        JOIN distribution.dbo.MSsubscriptions AS s (NOLOCK) ON (t.article_id = s.article_id AND t.publisher_database_id=s.publisher_database_id ) 
        JOIN 
            (SELECT hist.agent_id, MAX(hist.[time]) AS [time], h.maxseq  
            FROM distribution.dbo.MSdistribution_history hist (NOLOCK) 
            JOIN (SELECT agent_id,ISNULL(MAX(xact_seqno),0x0) AS maxseq 
            FROM distribution.dbo.MSdistribution_history (NOLOCK)  
            GROUP BY agent_id) AS h  
            ON (hist.agent_id=h.agent_id AND h.maxseq=hist.xact_seqno) 
            GROUP BY hist.agent_id, h.maxseq 
            ) AS MaxAgentValue 
        ON MaxAgentValue.agent_id = s.agent_id 
        GROUP BY s.agent_id, MaxAgentValue.[time] 
        ) und 
    ON mda.id = und.agent_id AND und.[time] = mdh.[time] 
    where mda.subscriber_db<>'virtual' -- created when your publication has the immediate_sync property set to true. This property dictates whether snapshot is available all the time for new subscriptions to be initialized. This affects the cleanup behavior of transactional replication. If this property is set to true, the transactions will be retained for max retention period instead of it getting cleaned up as soon as all the subscriptions got the change.
    --and mdh.runstatus='6' --Fail
    --and mdh.runstatus<>'2' --Succeed
    order by mdh.[time]

    Ref: http://stackoverflow.com/questions/220340/how-do-i-check-sql-replication-status-via-t-sql

    EDIT: You can remove unwanted info while executing. I just provided as it is from the reference site thinking that would be useful to you.
    • Edited by SQLZealots Wednesday, February 26, 2014 1:14 PM
    • Marked as answer by tracycai Monday, March 3, 2014 10:19 AM
    Wednesday, February 26, 2014 1:10 PM
  • use sp_helppublication and look at the allow_push or allow_pull columns. If the values are 1 the publication is enabled for push or pull.

    then use sp_helpsubscription and look at subsription_type column.

    0 = Push

    1 = Pull

    2 = Anonymous


    looking for a book on SQL Server 2008 Administration? http://www.amazon.com/Microsoft-Server-2008-Management-Administration/dp/067233044X looking for a book on SQL Server 2008 Full-Text Search? http://www.amazon.com/Pro-Full-Text-Search-Server-2008/dp/1430215941

    • Marked as answer by tracycai Monday, March 3, 2014 10:19 AM
    Wednesday, February 26, 2014 2:52 PM
    Answerer

All replies

  • Try the below:

    --First you find the distributor servername using the below running in publisher
    Use master
    EXEC sp_helpdistributor;
    
    --Then you can run the below to find the type (use distributor database)
    
    SELECT 
    (CASE  
        WHEN mdh.runstatus =  '1' THEN 'Start - '+cast(mdh.runstatus as varchar)
        WHEN mdh.runstatus =  '2' THEN 'Succeed - '+cast(mdh.runstatus as varchar)
        WHEN mdh.runstatus =  '3' THEN 'InProgress - '+cast(mdh.runstatus as varchar)
        WHEN mdh.runstatus =  '4' THEN 'Idle - '+cast(mdh.runstatus as varchar)
        WHEN mdh.runstatus =  '5' THEN 'Retry - '+cast(mdh.runstatus as varchar)
        WHEN mdh.runstatus =  '6' THEN 'Fail - '+cast(mdh.runstatus as varchar)
        ELSE CAST(mdh.runstatus AS VARCHAR)
    END) [Run Status], 
    mda.subscriber_db [Subscriber DB], 
    mda.publication [PUB Name],
    CONVERT(VARCHAR(25),mdh.[time]) [LastSynchronized],
    und.UndelivCmdsInDistDB [UndistCom], 
    mdh.comments [Comments], 
    'select * from distribution.dbo.msrepl_errors (nolock) where id = ' + CAST(mdh.error_id AS VARCHAR(8)) [Query More Info],
    mdh.xact_seqno [SEQ_NO],
    (CASE  
        WHEN mda.subscription_type =  '0' THEN 'Push' 
        WHEN mda.subscription_type =  '1' THEN 'Pull' 
        WHEN mda.subscription_type =  '2' THEN 'Anonymous' 
        ELSE CAST(mda.subscription_type AS VARCHAR)
    END) [SUB Type],
    
    mda.publisher_db+' - '+CAST(mda.publisher_database_id as varchar) [Publisher DB],
    mda.name [Pub - DB - Publication - SUB - AgentID]
    FROM distribution.dbo.MSdistribution_agents mda 
    LEFT JOIN distribution.dbo.MSdistribution_history mdh ON mdh.agent_id = mda.id 
    JOIN 
        (SELECT s.agent_id, MaxAgentValue.[time], SUM(CASE WHEN xact_seqno > MaxAgentValue.maxseq THEN 1 ELSE 0 END) AS UndelivCmdsInDistDB 
        FROM distribution.dbo.MSrepl_commands t (NOLOCK)  
        JOIN distribution.dbo.MSsubscriptions AS s (NOLOCK) ON (t.article_id = s.article_id AND t.publisher_database_id=s.publisher_database_id ) 
        JOIN 
            (SELECT hist.agent_id, MAX(hist.[time]) AS [time], h.maxseq  
            FROM distribution.dbo.MSdistribution_history hist (NOLOCK) 
            JOIN (SELECT agent_id,ISNULL(MAX(xact_seqno),0x0) AS maxseq 
            FROM distribution.dbo.MSdistribution_history (NOLOCK)  
            GROUP BY agent_id) AS h  
            ON (hist.agent_id=h.agent_id AND h.maxseq=hist.xact_seqno) 
            GROUP BY hist.agent_id, h.maxseq 
            ) AS MaxAgentValue 
        ON MaxAgentValue.agent_id = s.agent_id 
        GROUP BY s.agent_id, MaxAgentValue.[time] 
        ) und 
    ON mda.id = und.agent_id AND und.[time] = mdh.[time] 
    where mda.subscriber_db<>'virtual' -- created when your publication has the immediate_sync property set to true. This property dictates whether snapshot is available all the time for new subscriptions to be initialized. This affects the cleanup behavior of transactional replication. If this property is set to true, the transactions will be retained for max retention period instead of it getting cleaned up as soon as all the subscriptions got the change.
    --and mdh.runstatus='6' --Fail
    --and mdh.runstatus<>'2' --Succeed
    order by mdh.[time]

    Ref: http://stackoverflow.com/questions/220340/how-do-i-check-sql-replication-status-via-t-sql

    EDIT: You can remove unwanted info while executing. I just provided as it is from the reference site thinking that would be useful to you.
    • Edited by SQLZealots Wednesday, February 26, 2014 1:14 PM
    • Marked as answer by tracycai Monday, March 3, 2014 10:19 AM
    Wednesday, February 26, 2014 1:10 PM
  • use sp_helppublication and look at the allow_push or allow_pull columns. If the values are 1 the publication is enabled for push or pull.

    then use sp_helpsubscription and look at subsription_type column.

    0 = Push

    1 = Pull

    2 = Anonymous


    looking for a book on SQL Server 2008 Administration? http://www.amazon.com/Microsoft-Server-2008-Management-Administration/dp/067233044X looking for a book on SQL Server 2008 Full-Text Search? http://www.amazon.com/Pro-Full-Text-Search-Server-2008/dp/1430215941

    • Marked as answer by tracycai Monday, March 3, 2014 10:19 AM
    Wednesday, February 26, 2014 2:52 PM
    Answerer