Bu makalede Always-On Mimarisinde primary server ile secondary server arasında gerilik meydana gelmesi durumunda, gerilik farkını ve bilgilerini öğrenme adımlarını anlatacağız.
—Step 1: İlk olarak aşağıdaki tabloyu oluşturulur. Bu tabloda meydana gelen geriliğin bilgilerini tutacağız.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 |
USE [master] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE TABLE [dbo].[AGDBLatency]( [Collection_Time] [datetime] NOT NULL, [primary_replica] [nvarchar](256) NULL, [DatabaseName] [nvarchar](128) NULL, [secondary_replica] [nvarchar](256) NULL, [Pri_Last_Commit_Time] [datetime] NULL, [Sec_Last_Commit_Time] [datetime] NULL, [Sync_Lag_Secs] [int] NULL, [redo_queue_size_KB] [bigint] NULL, [redo_rate_KB_Sec] [bigint] NULL, [Redo_Lag_Secs] [bigint] NULL, [Synchronization_state_desc] [nvarchar](256) NULL ) ON [PRIMARY] GO |
—Step 2: Database’lerde meydana gelecek olan geriliklerin mail olarak atılabilmesi amacıyla mail hesapları oluşturulur. Siz sisteminizdeki mail özelliklerine göre hesaplarınızı oluşturunuz.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 |
USE msdb; — Create a user on the msdb database. This User Msdb Database user will be. If there is User. It need not to adding User. CREATE USER [DomainUser] FOR LOGIN [DomainUser] ; — Create a Database Mail account EXECUTE msdb.dbo.sysmail_add_account_sp @account_name = ‘DB Admin Lag’, @description = ‘DB Gerililik Olduğunda Mail Gönderme Hesabı.’, @email_address = ‘SerdarBayrak@business.com.tr’, @replyto_address = ‘reply@example.com’, @display_name = ‘AlwaysOn Lag’, @mailserver_name = ‘eposta.business.com.tr’, @port = 25; — Create a Database Mail profile EXECUTE msdb.dbo.sysmail_add_profile_sp @profile_name = ‘AlwaysOn Lag’, @description = ‘DB Gerililik Olduğunda Mail Gönderme Profili.’; — Add the account to the profile EXECUTE msdb.dbo.sysmail_add_profileaccount_sp @profile_name = ‘AlwaysOn Lag’, @account_name = ‘DB Admin Lag’, @sequence_number = 1; — Grant user access to the Database Mail profile EXECUTE msdb.dbo.sysmail_add_principalprofile_sp @profile_name = ‘AlwaysOn Lag’, @principal_name = ‘DomainUser’, @is_default = 1; |
—Step 3: Database’ler de meydana gelen geriliklerin farkını öğrenebilmek için aşağıdaki jobu oluşturacağız. Bu sayede hangi database’de ne kadar gerilik oluşmuş bunu yukarıda oluşturduğumuz tablo içerisine insert edeceğiz. Biz sorgumuzda içerisinde gerilik eğer 300 sn’den fazla ise tabloya insert ediyoruz.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 |
USE [msdb] GO BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]’ AND category_class=1) BEGIN EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N’JOB’, @type=N’LOCAL’, @name=N'[Uncategorized (Local)]’ IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback END DECLARE @jobId BINARY(16) EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N’AGDBLatency’, @enabled=1, @notify_level_eventlog=0, @notify_level_email=0, @notify_level_netsend=0, @notify_level_page=0, @delete_level=0, @description=N’DB Latency”lerini AdminDB”ye log”lar’, @category_name=N'[Uncategorized (Local)]’, @owner_login_name=N’sa’, @job_id = @jobId OUTPUT IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N’StepOne’, @step_id=1, @cmdexec_success_code=0, @on_success_action=1, @on_success_step_id=0, @on_fail_action=2, @on_fail_step_id=0, @retry_attempts=0, @retry_interval=0, @os_run_priority=0, @subsystem=N’TSQL’, @command=N’;WITH AG_Stats AS ( SELECT AR.replica_server_name, HARS.role_desc, Db_name(DRS.database_id) [DBName], DRS.last_commit_time, DRS.redo_queue_size redo_queue_size_KB, DRS.redo_rate redo_rate_KB_Sec, DRS.synchronization_state_desc FROM sys.dm_hadr_database_replica_states DRS INNER JOIN sys.availability_replicas AR ON DRS.replica_id = AR.replica_id INNER JOIN sys.dm_hadr_availability_replica_states HARS ON AR.group_id = HARS.group_id AND AR.replica_id = HARS.replica_id ), Pri_CommitTime AS ( SELECT replica_server_name , DBName , last_commit_time , redo_queue_size_KB , redo_rate_KB_Sec , synchronization_state_desc FROM AG_Stats WHERE role_desc = ”PRIMARY” ), Sec_CommitTime AS ( SELECT replica_server_name , DBName , last_commit_time , redo_queue_size_KB , redo_rate_KB_Sec , synchronization_state_desc FROM AG_Stats WHERE role_desc = ”SECONDARY” ) insert master.dbo.AGDBLatency SELECT getdate() as Collection_Time , p.replica_server_name [primary_replica] , p.[DBName] AS [DatabaseName] , s.replica_server_name [secondary_replica] , p.last_commit_time as Pri_Last_Commit_Time , s.last_commit_time as Sec_Last_Commit_Time , DATEDIFF(ss,s.last_commit_time,p.last_commit_time) AS [Sync_Lag_Secs] , s.redo_queue_size_KB , s.redo_rate_KB_Sec , case s.redo_rate_KB_Sec when 0 then 0 else CAST(s.redo_queue_size_KB / s.redo_rate_KB_Sec / 60 AS BIGINT) end [Redo_Lag_Secs] , s.synchronization_state_desc FROM Pri_CommitTime p LEFT JOIN Sec_CommitTime s ON [s].[DBName] = [p].[DBName] –where DATEDIFF(ss,s.last_commit_time,p.last_commit_time)>100 WHERe [s].[DBName] in (select db.[name] from sys.databases db where db.database_id > 4) –and ISNULL(s.redo_queue_size_KB / NULLIF(s.redo_rate_KB_Sec,0),0) > 0 and DATEDIFF(ss,s.last_commit_time,p.last_commit_time) > 300 order by Collection_Time asc USE [master] EXEC [dbo].[USP_AlwaysOn] ‘, @database_name=N’master’, @flags=0 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N’sc1′, @enabled=1, @freq_type=4, @freq_interval=1, @freq_subday_type=4, @freq_subday_interval=15, @freq_relative_interval=0, @freq_recurrence_factor=0, @active_start_date=20200225, @active_end_date=99991231, @active_start_time=0, @active_end_time=235959, @schedule_uid=N’d75a44f6-8869-4a25-83e5-a5bc422092c5′ IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)’ IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback COMMIT TRANSACTION GOTO EndSave QuitWithRollback: IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION EndSave: GO |
–Step 4: Gerilik bilgileri bir tabloya kaydettikten sonra aşağıdaki procedure ile kaydedilen gerilik bilgilerini yukarıda oluşturduğumuz html yapıda yukarıda oluşturduğumuz hesaba mail göndermesini sağlıyoruz.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 |
USE [master] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [dbo].[USP_AlwaysOn] AS SET NOCOUNT ON; BEGIN DECLARE @xml NVARCHAR(MAX) DECLARE @body NVARCHAR(MAX) DECLARE @DonenKayit INT, @Sorgu NVARCHAR(1000) Set @DonenKayit = 0 Set @Sorgu = N'Select @DonenKayitSayisi = COUNT(*) from master.dbo.AGDBLatency with (nolock) GROUP BY Collection_Time HAVING DATEDIFF(MINUTE,Collection_Time,getdate()) < 30 ORDER BY Collection_Time DESC' Set @xml = ((SELECT STUFF((select top 5 Collection_Time as 'td','' ,primary_replica as 'td','' ,secondary_replica as 'td','' ,DatabaseName as 'td','' ,Pri_Last_Commit_Time as 'td','' ,Sec_Last_Commit_Time as 'td','' ,CONVERT(varchar(5),DATEDIFF(s,Sec_Last_Commit_Time, Pri_Last_Commit_Time)/3600)+ ':' +CONVERT(varchar(5),DATEDIFF(s,Sec_Last_Commit_Time, Pri_Last_Commit_Time)%3600/60)+ ':' +CONVERT(varchar(5),DATEDIFF(s,Sec_Last_Commit_Time, Pri_Last_Commit_Time)%60) as 'td','' ,Sync_Lag_Secs as 'td','' ,redo_queue_size_KB as 'td','' ,redo_rate_KB_Sec as 'td','' ,Redo_Lag_Secs as 'td','' ,Synchronization_state_desc as 'td','' from dbo.AGDBLatency ORDER BY Collection_Time desc FOR XML PATH('tr')),1,0,'') )) SET @body =' 'SET @body = @body + @xml + ' <table border="1"> <tbody> <tr> <th>Collection Time</th> <th>Primary Replica Server</th> <th>Secondary Replica Server</th> <th>Database Name</th> <th>Primary Last Commit Time</th> <th>Secondary Last Commit Time</th> <th>Time Lag</th> <th>Sync Lag Secs</th> <th>Redo Queue Size</th> <th>Redo Rate KB/Sec</th> <th>Redo Lag Secs</th> <th>Synchronization_state_desc</th> </tr> </tbody> </table> ' EXECUTE SP_EXECUTESQL @Sorgu,N'@DonenKayitSayisi INT OUTPUT', @DonenKayitSayisi = @DonenKayit OUTPUT; If @DonenKayit > 0 Begin exec msdb.dbo.sp_send_dbmail @profile_name = 'AlwaysOn', @recipients = 'SerdarBayrak@business.com.tr', @Subject = 'AlwaysOn Lag', @body = @body , @body_format = 'HTML' END END GO |