Query to Monitor Replication Performance Issues

  • I am having performance issues with this query.. but not sure how to get it to run properly.. it goes into IO_Completion and does not come out.. at least 12 hours.

    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],

    right(left(mda.name,LEN(mda.name)-(len(mda.id)+1)), LEN(left(mda.name,LEN(mda.name)-(len(mda.id)+1)))-(10+len(mda.publisher_db)+(case when mda.publisher_db='ALL' then 1 else LEN(mda.publication)+2 end))) [SUBSCRIBER],

    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) ,

    mda.publisher_db+' - '+CAST(mda.publisher_database_id as varchar) [Publisher DB],

    mda.name [Pub - DB - Publication - SUB - AgentID]

    into #publish

    FROM distribution.dbo.MSdistribution_agents mda

    inner join msdb.dbo.sysjobs sysjob

    on mda.job_id = sysjob.job_id

    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' --and mdh.runstatus='6' --Fail

    --and mdh.runstatus<>'2' --Succeed

    order by mdh.[time]

  • Not sure if we should put an index into this database... but the following fixed the issue:

    CREATE NONCLUSTERED INDEX [IX_MSRepl_Commands_Art_Pub] ON [dbo].[MSrepl_commands]

    (

    [article_id] ASC,

    [publisher_database_id] ASC

    )

    INCLUDE ( [xact_seqno]) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = ON, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]

    GO

Viewing 2 posts - 1 through 1 (of 1 total)

You must be logged in to reply to this topic. Login to reply