Skip to content

Commit b131511

Browse files
author
Ajay Dwivedi
committed
Added few scripts for Replication Issues
Added few scripts for Replication Issues
1 parent 5fc9565 commit b131511

8 files changed

+418
-0
lines changed
1.5 KB
Binary file not shown.
Lines changed: 96 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,96 @@
1+
DECLARE @profile_name VARCHAR(100) = @@servername
2+
DECLARE @strsubject VARCHAR(100)
3+
DECLARE @tableHTML NVARCHAR(max)
4+
DECLARE @EmailRecipients VARCHAR(max) = '[email protected]'
5+
6+
CREATE TABLE #agentHistory (
7+
ServerName NVARCHAR (64)
8+
,Publication NVARCHAR (64)
9+
,AgentName NVARCHAR(512)
10+
,LastMsgTime DATETIME
11+
)
12+
13+
;WITH CTE ( server_name,publication,agent_name,last_update) AS
14+
(
15+
SELECT
16+
srvr.srvname
17+
,agent.publication
18+
,agent.NAME
19+
,MAX(history.TIME)
20+
FROM MSdistribution_agents agent
21+
INNER JOIN msdistribution_history history ON history.agent_id = agent.id
22+
INNER JOIN sys.sysservers srvr on srvr.srvid = agent.subscriber_id
23+
GROUP BY srvr.srvname,agent.publication,agent.NAME
24+
)
25+
INSERT INTO #agentHistory
26+
SELECT server_name,publication,agent_name,last_update from CTE
27+
WHERE last_update < dateadd(MINUTE, - 30, getdate())
28+
29+
IF EXISTS (
30+
SELECT *
31+
FROM #agentHistory
32+
)
33+
BEGIN
34+
SELECT @strsubject = 'Replication Agent Alert ' + convert(VARCHAR(17), getdate(), 113) + ' ***'
35+
36+
SET @tableHTML = N'<H1>Replication Agent has not Logged a Message</H1>' + N'<h3>One or more agents have not logged an update in the last 30 minutes</h3>' + N'<table border="1">' + N'<tr><th>Server Name</th>'+ N'<th>Publication</th>'+ N'<th>Agent Name</th>' + N'<th>Last Updated Time</th>' + '</tr>' + cast((
37+
SELECT td = AH.ServerName
38+
,''
39+
,td = AH.Publication
40+
,''
41+
,td = AH.AgentName
42+
,''
43+
,td = AH.LastMsgTime
44+
,''
45+
FROM #agentHistory AH
46+
FOR XML path('tr')
47+
,type
48+
) AS NVARCHAR(max)) + N'</table>' + CHAR (10) + CHAR (13) +
49+
50+
'<p> In order to resolve this, log onto the server, start up SQL Server and find the job under "SQL Server Agent -> Jobs". If job is stopped, right click and select "start job at step". The job will start running. Do not wait for it to complete as the job runs continuously. If the same jobs alerts again raise the issue with the DBA Team. '
51+
52+
EXEC msdb.dbo.sp_send_dbmail @recipients = @EmailRecipients
53+
,@subject = @strsubject
54+
,@body = @tableHTML
55+
,@body_format = 'HTML'
56+
,@profile_name = @profile_name
57+
END
58+
59+
DECLARE @COUNT INT
60+
DECLARE @PostLog BIT = 0
61+
DECLARE @@SERVER_NAME VARCHAR (128)
62+
DECLARE @@AGENTNAME VARCHAR (128) = ''
63+
DECLARE @@PUBLICATION VARCHAR (128) = ''
64+
65+
DECLARE @@MESSAGE varchar(2000)
66+
DECLARE @@MSG_ARRAY varchar (2000) = ''
67+
68+
SELECT @COUNT = COUNT (*) FROM #agentHistory
69+
SELECT @PostLog = CASE WHEN @COUNT > 0 THEN 1 ELSE 0 END
70+
WHILE @COUNT > 0
71+
BEGIN
72+
73+
SELECT @@AGENTNAME = MAX (Ah.AgentName) FROM #agentHistory AH
74+
75+
SELECT @@MESSAGE = 'Agents have not logged a message. Log on to server, open SQL Server Management Studio and start job if not running. If job continues to alert that it has stopped then contact DBA Team.
76+
If job is running then monitor and close ticket when agents no longer alert.'
77+
SELECT @@MSG_ARRAY = @@AGENTNAME + ' ' + CHAR(10) + CHAR(13) + @@MSG_ARRAY + ' '
78+
79+
SET @COUNT = @COUNT - 1
80+
81+
DELETE FROM #agentHistory where AgentName = @@AGENTNAME
82+
83+
SELECT @@MESSAGE = @@MESSAGE + CHAR(10) + CHAR(13) +@@MSG_ARRAY
84+
85+
END
86+
87+
IF @PostLog = 1
88+
89+
BEGIN
90+
91+
USE master
92+
EXEC xp_logevent 68320, @@MESSAGE, error
93+
94+
END
95+
96+
DROP TABLE #agentHistory
Lines changed: 106 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,106 @@
1+
use distribution;
2+
3+
set nocount on;
4+
declare @verbose bit = 0;
5+
6+
if @verbose = 1
7+
print 'Declaring local variables..';
8+
declare @currentTime datetime;
9+
declare @recepients varchar(2000);
10+
declare @mailBody varchar(4000);
11+
declare @mailSubject varchar(500);
12+
declare @agent_job_name varchar(500);
13+
declare @agent_job_id varbinary(16);
14+
declare @publisher varchar(200);
15+
declare @subscriber varchar(200);
16+
declare @publisher_db varchar(200);
17+
declare @subscriber_db varchar(200);
18+
declare @publication varchar(500);
19+
declare @agent_start_time datetime;
20+
declare @agent_last_log_time datetime;
21+
declare @agent_last_log_threshold_minutes int;
22+
select @currentTime = GETDATE();
23+
--select @currentTime = cast('2020-01-28 20:15:00.000' as datetime);
24+
set @recepients = '[email protected];';
25+
set @agent_last_log_threshold_minutes = 20;
26+
27+
if @verbose = 1
28+
print 'Declaring cursor..';
29+
DECLARE cursor_distributor_agent CURSOR LOCAL FAST_FORWARD FOR
30+
select a.name as agent_job_name, a.job_id as agent_job_id, p.name as publisher, s.name as subscriber, a.publisher_db, a.subscriber_db, a.publication
31+
from distribution.dbo.MSdistribution_agents as a
32+
left join master.sys.servers as p on p.server_id = a.publisher_id
33+
left join master.sys.servers as s on s.server_id = a.subscriber_id
34+
where a.local_job = 1
35+
--and a.name = 'TUL1CIPCNPDB1-Babel-BabelDE-TUL1CIPXDB13-59';
36+
37+
OPEN cursor_distributor_agent;
38+
FETCH NEXT FROM cursor_distributor_agent INTO @agent_job_name, @agent_job_id, @publisher, @subscriber, @publisher_db, @subscriber_db, @publication;
39+
40+
WHILE @@FETCH_STATUS = 0
41+
BEGIN
42+
if @verbose = 1
43+
print 'Evaluating variables for distribution agent job '''+@agent_job_name+'''';
44+
45+
select @agent_start_time = case when max(h.time) is not null then max(h.time) else DATEADD(hour,-48,getdate()) end
46+
from distribution.dbo.MSdistribution_history as h
47+
left join distribution.dbo.MSdistribution_agents as a on a.id = h.agent_id
48+
where a.name = @agent_job_name
49+
and h.runstatus = 1; -- Start
50+
--and h.comments in ('Starting agent.');
51+
52+
select @agent_last_log_time = case when max(h.time) is not null then max(h.time) else @agent_start_time end
53+
from distribution.dbo.MSdistribution_history as h
54+
left join distribution.dbo.MSdistribution_agents as a on a.id = h.agent_id
55+
where a.name = @agent_job_name
56+
and h.time >= @agent_start_time
57+
and h.runstatus = 3; -- In Progress
58+
--and h.comments not in ('Starting agent.','Initializing')
59+
60+
if @verbose = 1
61+
begin
62+
if DATEDIFF(MINUTE,@agent_last_log_time,@currentTime) > @agent_last_log_threshold_minutes
63+
begin
64+
select @currentTime as [@currentTime], @agent_job_name as [@agent_job_name], @agent_start_time as [@agent_start_time], @agent_last_log_time as [@agent_last_log_time];
65+
print 'ISSUE';
66+
end
67+
else
68+
print 'no issue';
69+
end
70+
71+
/*
72+
select getdate() as currentTime, a.name as agent_job_name, a.publication, a.subscriber_db, a.job_id, h.runstatus, h.start_time, h.time as agent_log_time, h.comments
73+
from distribution.dbo.MSdistribution_history as h
74+
left join MSdistribution_agents as a on a.id = h.agent_id
75+
where a.name = @agent_job_name
76+
and h.time >= @agent_start_time
77+
and h.runstatus = 3 -- In Progress
78+
order by agent_log_time desc;
79+
*/
80+
81+
if DATEDIFF(MINUTE,@agent_last_log_time,@currentTime) > @agent_last_log_threshold_minutes
82+
begin
83+
print 'Distribution Agent - Start /Stop in T-SQL';
84+
85+
-- To STOP the Distribution Agent:
86+
exec distribution..sp_MSstopdistribution_agent @publisher, @publisher_db, @publication, @subscriber, @subscriber_db;
87+
--
88+
WAITFOR DELAY '00:00:05'; -- 5 Seconds
89+
--
90+
--To START the Distribution Agent:
91+
exec distribution..sp_MSstartdistribution_agent @publisher, @publisher_db, @publication, @subscriber, @subscriber_db;
92+
93+
set @mailSubject = 'Distribution Agent - '+QUOTENAME(@agent_job_name)+' restarted';
94+
set @mailBody = 'Distribution Agent job '+QUOTENAME(@agent_job_name)+' restarted has been restarted as it did not log any messages in last '+cast(@agent_last_log_threshold_minutes as varchar(20))+' minutes.';
95+
EXEC msdb.dbo.sp_send_dbmail
96+
--@profile_name = 'Adventure Works Administrator',
97+
@recipients = @recepients,
98+
@body = @mailBody,
99+
@subject = @mailSubject ;
100+
end
101+
102+
FETCH NEXT FROM cursor_distributor_agent INTO @agent_job_name, @agent_job_id, @publisher, @subscriber, @publisher_db, @subscriber_db, @publication;
103+
END
104+
105+
CLOSE cursor_distributor_agent;
106+
DEALLOCATE cursor_distributor_agent;
Lines changed: 106 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,106 @@
1+
use distribution;
2+
3+
set nocount on;
4+
declare @verbose bit = 0;
5+
6+
if @verbose = 1
7+
print 'Declaring local variables..';
8+
declare @currentTime datetime;
9+
declare @recepients varchar(2000);
10+
declare @mailBody varchar(4000);
11+
declare @mailSubject varchar(500);
12+
declare @agent_job_name varchar(500);
13+
declare @agent_job_id varbinary(16);
14+
declare @publisher varchar(200);
15+
declare @subscriber varchar(200);
16+
declare @publisher_db varchar(200);
17+
declare @subscriber_db varchar(200);
18+
declare @publication varchar(500);
19+
declare @agent_start_time datetime;
20+
declare @agent_last_log_time datetime;
21+
declare @agent_last_log_threshold_minutes int;
22+
select @currentTime = GETDATE();
23+
--select @currentTime = cast('2020-01-28 20:15:00.000' as datetime);
24+
set @recepients = '[email protected]; [email protected];';
25+
set @agent_last_log_threshold_minutes = 20;
26+
27+
if @verbose = 1
28+
print 'Declaring cursor..';
29+
DECLARE cursor_distributor_agent CURSOR LOCAL FAST_FORWARD FOR
30+
select a.name as agent_job_name, a.job_id as agent_job_id, p.name as publisher, s.name as subscriber, a.publisher_db, a.subscriber_db, a.publication
31+
from distribution.dbo.MSdistribution_agents as a
32+
left join master.sys.servers as p on p.server_id = a.publisher_id
33+
left join master.sys.servers as s on s.server_id = a.subscriber_id
34+
where a.local_job = 1
35+
--and a.name = 'TUL1CIPCNPDB1-Babel-BabelDE-TUL1CIPXDB13-59';
36+
37+
OPEN cursor_distributor_agent;
38+
FETCH NEXT FROM cursor_distributor_agent INTO @agent_job_name, @agent_job_id, @publisher, @subscriber, @publisher_db, @subscriber_db, @publication;
39+
40+
WHILE @@FETCH_STATUS = 0
41+
BEGIN
42+
if @verbose = 1
43+
print 'Evaluating variables for distribution agent job '''+@agent_job_name+'''';
44+
45+
select @agent_start_time = case when max(h.time) is not null then max(h.time) else DATEADD(hour,-48,getdate()) end
46+
from distribution.dbo.MSdistribution_history as h
47+
left join distribution.dbo.MSdistribution_agents as a on a.id = h.agent_id
48+
where a.name = @agent_job_name
49+
and h.runstatus = 1; -- Start
50+
--and h.comments in ('Starting agent.');
51+
52+
select @agent_last_log_time = case when max(h.time) is not null then max(h.time) else @agent_start_time end
53+
from distribution.dbo.MSdistribution_history as h
54+
left join distribution.dbo.MSdistribution_agents as a on a.id = h.agent_id
55+
where a.name = @agent_job_name
56+
and h.time >= @agent_start_time
57+
and h.runstatus = 3; -- In Progress
58+
--and h.comments not in ('Starting agent.','Initializing')
59+
60+
if @verbose = 1
61+
begin
62+
if DATEDIFF(MINUTE,@agent_last_log_time,@currentTime) > @agent_last_log_threshold_minutes
63+
begin
64+
select @currentTime as [@currentTime], @agent_job_name as [@agent_job_name], @agent_start_time as [@agent_start_time], @agent_last_log_time as [@agent_last_log_time];
65+
print 'ISSUE';
66+
end
67+
else
68+
print 'no issue';
69+
end
70+
71+
/*
72+
select getdate() as currentTime, a.name as agent_job_name, a.publication, a.subscriber_db, a.job_id, h.runstatus, h.start_time, h.time as agent_log_time, h.comments
73+
from distribution.dbo.MSdistribution_history as h
74+
left join MSdistribution_agents as a on a.id = h.agent_id
75+
where a.name = @agent_job_name
76+
and h.time >= @agent_start_time
77+
and h.runstatus = 3 -- In Progress
78+
order by agent_log_time desc;
79+
*/
80+
81+
if DATEDIFF(MINUTE,@agent_last_log_time,@currentTime) > @agent_last_log_threshold_minutes
82+
begin
83+
print 'Distribution Agent - Start /Stop in T-SQL';
84+
85+
-- To STOP the Distribution Agent:
86+
exec distribution..sp_MSstopdistribution_agent @publisher, @publisher_db, @publication, @subscriber, @subscriber_db;
87+
--
88+
WAITFOR DELAY '00:00:05'; -- 5 Seconds
89+
--
90+
--To START the Distribution Agent:
91+
exec distribution..sp_MSstartdistribution_agent @publisher, @publisher_db, @publication, @subscriber, @subscriber_db;
92+
93+
set @mailSubject = 'Distribution Agent - '+QUOTENAME(@agent_job_name)+' restarted';
94+
set @mailBody = 'Distribution Agent job '+QUOTENAME(@agent_job_name)+' restarted has been restarted as it did not log any messages in last '+cast(@agent_last_log_threshold_minutes as varchar(20))+' minutes.';
95+
EXEC msdb.dbo.sp_send_dbmail
96+
--@profile_name = 'Adventure Works Administrator',
97+
@recipients = @recepients,
98+
@body = @mailBody,
99+
@subject = @mailSubject ;
100+
end
101+
102+
FETCH NEXT FROM cursor_distributor_agent INTO @agent_job_name, @agent_job_id, @publisher, @subscriber, @publisher_db, @subscriber_db, @publication;
103+
END
104+
105+
CLOSE cursor_distributor_agent;
106+
DEALLOCATE cursor_distributor_agent;

Replication-Transactional/Replication-Transactional.ssmssqlproj

Lines changed: 36 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -27,6 +27,18 @@
2727
<ConnectionProtocol>NotSpecified</ConnectionProtocol>
2828
<ApplicationName>Microsoft SQL Server Management Studio - Query</ApplicationName>
2929
</ConnectionNode>
30+
<ConnectionNode Name="TUL1MDPDWDIS02:CORPORATE\adwivedi">
31+
<Created>2020-01-29T14:13:45.713431+05:30</Created>
32+
<Type>SQL</Type>
33+
<Server>TUL1MDPDWDIS02</Server>
34+
<UserName />
35+
<Authentication>Windows Authentication</Authentication>
36+
<InitialDB />
37+
<LoginTimeout>30</LoginTimeout>
38+
<ExecutionTimeout>0</ExecutionTimeout>
39+
<ConnectionProtocol>NotSpecified</ConnectionProtocol>
40+
<ApplicationName>Microsoft SQL Server Management Studio - Query</ApplicationName>
41+
</ConnectionNode>
3042
</Items>
3143
</LogicalFolder>
3244
<LogicalFolder Name="Queries" Type="0" Sorted="true">
@@ -109,12 +121,36 @@
109121
<AssociatedConnUserName />
110122
<FullPath>Backup-Restore.sql</FullPath>
111123
</FileNode>
124+
<FileNode Name="DBA - Replication Agent Job monitoring.sql">
125+
<AssociatedConnectionMoniker>8c91a03d-f9b4-46c0-a305-b5dcc79ff907:(local):True</AssociatedConnectionMoniker>
126+
<AssociatedConnSrvName>(local)</AssociatedConnSrvName>
127+
<AssociatedConnUserName />
128+
<FullPath>DBA - Replication Agent Job monitoring.sql</FullPath>
129+
</FileNode>
130+
<FileNode Name="DBA - Replication Distribution Agent Check.sql">
131+
<AssociatedConnectionMoniker>8c91a03d-f9b4-46c0-a305-b5dcc79ff907:(local):True</AssociatedConnectionMoniker>
132+
<AssociatedConnSrvName>(local)</AssociatedConnSrvName>
133+
<AssociatedConnUserName />
134+
<FullPath>DBA - Replication Distribution Agent Check.sql</FullPath>
135+
</FileNode>
136+
<FileNode Name="dbo.usp_replication_agent_checkup .sql">
137+
<AssociatedConnectionMoniker>8c91a03d-f9b4-46c0-a305-b5dcc79ff907:TUL1MDPDWDIS02:True</AssociatedConnectionMoniker>
138+
<AssociatedConnSrvName>TUL1MDPDWDIS02</AssociatedConnSrvName>
139+
<AssociatedConnUserName />
140+
<FullPath>dbo.usp_replication_agent_checkup .sql</FullPath>
141+
</FileNode>
112142
<FileNode Name="How-2-Enable-Agent-Logging.sql">
113143
<AssociatedConnectionMoniker />
114144
<AssociatedConnSrvName />
115145
<AssociatedConnUserName />
116146
<FullPath>How-2-Enable-Agent-Logging.sql</FullPath>
117147
</FileNode>
148+
<FileNode Name="MSdistribution_history.sql">
149+
<AssociatedConnectionMoniker>8c91a03d-f9b4-46c0-a305-b5dcc79ff907:TUL1MDPDWDIS02:True</AssociatedConnectionMoniker>
150+
<AssociatedConnSrvName>TUL1MDPDWDIS02</AssociatedConnSrvName>
151+
<AssociatedConnUserName />
152+
<FullPath>MSdistribution_history.sql</FullPath>
153+
</FileNode>
118154
<FileNode Name="Repl - ReplicationSupportOnly.sql">
119155
<AssociatedConnectionMoniker />
120156
<AssociatedConnSrvName />

Replication-Transactional/__Resources.sql

Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -13,6 +13,13 @@ https://www.mssqltips.com/sqlservertip/1808/sql-server-replication-scripts-to-ge
1313
8) Add article to transactional publication without generating new snapshot
1414
https://dba.stackexchange.com/questions/12725/add-article-to-transactional-publication-without-generating-new-snapshot
1515

16+
9)
17+
https://docs.microsoft.com/en-us/sql/relational-databases/system-tables/msdistribution-history-transact-sql?view=sql-server-ver15
18+
https://stackoverflow.com/questions/16482454/distribution-dbo-msdistribution-history-comments-explanation
19+
https://flylib.com/books/en/2.908.1.93/1/
20+
http://maginaumova.com/the-replication-agent-has-not-logged-a-progress-message-in-10-minutes/
21+
https://dba.stackexchange.com/questions/86794/how-to-restart-the-distributor-agent-of-transactional-replication
22+
1623
Rules:-
1724
-----
1825
1) Log Reader agent always resides at Distributor

0 commit comments

Comments
 (0)