1.需求概括 我們知道,在SQL Server Alwayson 架構中,有多種虛擬IP,例如 WindowsCluster IP,ListenIP,角色高可用性IP(類似於偵聽IP)。在某些條件下,例如系統故障,會觸發虛擬IP的漂移,如何高效率、低延遲、更好地監控IP漂移情況,是我們DB的一個重要 ...
1.需求概括
我們知道,在SQL Server Alwayson 架構中,有多種虛擬IP,例如 WindowsCluster IP,ListenIP,角色高可用性IP(類似於偵聽IP)。在某些條件下,例如系統故障,會觸發虛擬IP的漂移,如何高效率、低延遲、更好地監控IP漂移情況,是我們DB的一個重要工作。
下麵是我們的一個通過SQL Server 存儲過程來實現的方案。
2.基本原理
周期性收集當前Server 上相應的IP地址,並與上個周期收集的結果比較判斷,看那些IP發生了漂移變化。其主要流程圖如下;
3.代碼實現
表 DBA_ServerIPDataBase_OverCheck,主要存儲 當前 (本收集周期) Server的信息(主要是IP信息、ServerName信息等),其創建腳本如下;
/****** Object: Table [dbo].[DBA_ServerIPDataBase_OverCheck] Script Date: 2019/6/27 16:01:27 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO SET ANSI_PADDING ON GO CREATE TABLE [dbo].[DBA_ServerIPDataBase_OverCheck]( [LocalServerIP] [varchar](20) NULL, [ClusterName] [varchar](50) NULL, [ServerIP] [varchar](20) NULL, [ServerName] [varchar](100) NULL, [ServerFullName] [varchar](100) NULL, [ServerIPType] [varchar](20) NULL, [DataBaseName] [varchar](300) NULL, [DisabledFlag] [varchar](1) NULL, [CreateTime] [datetime] NULL, [CreateBy] [varchar](50) NULL, [ModifyTime] [datetime] NULL, [ModifyBy] [varchar](50) NULL ) ON [PRIMARY] GO SET ANSI_PADDING OFF GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'Windows集群名稱' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DBA_ServerIPDataBase_OverCheck', @level2type=N'COLUMN',@level2name=N'ClusterName' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'IP地址' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DBA_ServerIPDataBase_OverCheck', @level2type=N'COLUMN',@level2name=N'ServerIP' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'電腦對象名稱' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DBA_ServerIPDataBase_OverCheck', @level2type=N'COLUMN',@level2name=N'ServerName' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'電腦對象全稱' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DBA_ServerIPDataBase_OverCheck', @level2type=N'COLUMN',@level2name=N'ServerFullName' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'電腦對象全稱' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DBA_ServerIPDataBase_OverCheck', @level2type=N'COLUMN',@level2name=N'ServerIPType' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'0實時有效,1第一次失效,2第二次失效,3第三次失效,4第四次失效,5第五次失效,徹底刪除' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DBA_ServerIPDataBase_OverCheck', @level2type=N'COLUMN',@level2name=N'DisabledFlag' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'創建時間' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DBA_ServerIPDataBase_OverCheck', @level2type=N'COLUMN',@level2name=N'CreateTime' GO EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'創建人' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'DBA_ServerIPDataBase_OverCheck', @level2type=N'COLUMN',@level2name=N'CreateBy' GO
表 DBA_ServerIPDataBase_OverCheckOriginOrigin,主要存儲 以前 (前一個收集周期) Server的信息,是用來比較變化的基準表,其表結構 與表DBA_ServerIPDataBase_OverCheck相同,創建腳本如下:
/****** Object: Table [dbo].[DBA_ServerIPDataBase_OverCheckOriginOrigin] Script Date: 2019/6/27 16:56:28 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO SET ANSI_PADDING ON GO CREATE TABLE [dbo].[DBA_ServerIPDataBase_OverCheckOriginOrigin]( [LocalServerIP] [varchar](20) NULL, [ClusterName] [varchar](50) NULL, [ServerIP] [varchar](20) NULL, [ServerName] [varchar](100) NULL, [ServerFullName] [varchar](100) NULL, [ServerIPType] [varchar](20) NULL, [DataBaseName] [varchar](300) NULL, [DisabledFlag] [varchar](1) NULL, [CreateTime] [datetime] NULL, [CreateBy] [varchar](50) NULL, [ModifyTime] [datetime] NULL, [ModifyBy] [varchar](50) NULL ) ON [PRIMARY] GO SET ANSI_PADDING OFF GO
具體的存儲過程 USP_DBA_ServerIPDataBase_OverCheck,用來實現 收集、比較、告警等功能,代碼實現如下:
/****** Object: StoredProcedure [dbo].[USP_DBA_ServerIPDataBase_OverCheck] Script Date: 2019/6/27 15:26:06 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [dbo].[USP_DBA_ServerIPDataBase_OverCheck] AS BEGIN DECLARE @ipline VARCHAR(200) DECLARE @ip VARCHAR(20) DECLARE @pingname VARCHAR(40) DECLARE @ServerName VARCHAR(100) DECLARE @ServerFullName VARCHAR(100) Declare @CurrDateTime nvarchar(20) Declare @PreDiffDateTime nvarchar(20) ='' Set @CurrDateTime=CONVERT(VARCHAR(19),GETDATE(),120) SET NOCOUNT ON Declare @ServerIP VARCHAR(20) SET @ServerName=@@SERVERNAME SET @ServerIP = CAST(CONNECTIONPROPERTY('local_net_address') AS varchar(20)) ----Set @ServerIP ='XXX.XXX.XXX.XXX' --如果不准確的話,請手動定義 DELETE FROM DBA_ServerIPDataBase_OverCheck WHERE CreateTime< CONVERT(VARCHAR(19),DATEADD( HH,-10,GETDATE()),120) SET @ip = NULL IF OBJECT_ID('tempdb..#tempserverip') IS NOT NULL DROP TABLE #tempserverip CREATE TABLE #tempserverip ( ipline VARCHAR(200) ) INSERT #tempserverip EXEC master..xp_cmdshell 'ipconfig /all ' INSERT INTO DBA_ServerIPDataBase_OverCheck ( LocalServerIP,ServerIP,DisabledFlag,CreateTime,CreateBy ) SELECT @ServerIP, p.ServerIP,'0'AS DisabledFlag,GETDATE() AS CreateTime ,@@SERVERNAME AS CreateBy FROM dbo.DBA_ServerIPDataBase_OverCheck i RIGHT JOIN ( SELECT RTRIM(LTRIM(REPLACE(SUBSTRING(ipline, CHARINDEX(':', ipline) + 1, 20), '(首選)', ''))) AS 'ServerIP' FROM #tempserverip WHERE UPPER(ipline) LIKE '%IPv4 地址%'--這裡需要註意一下,系統不同這裡的匹配值就不同 AND UPPER(ipline) NOT LIKE '%192.168.%' AND UPPER(ipline) NOT LIKE '%169.254.%' ) p ON i.ServerIP = p.ServerIP WHERE i.ServerIP IS NULL --只關註漂來飄往數據 --0002 -20180530 針對20180530持續告警問題,發現告警時間超過預期,進行優化。聚焦點再表DBA_ServerIPDataBase_OverCheck中的CreateTime欄位,精準更新 begin update i set i.CreateTime=getdate() FROM dbo.DBA_ServerIPDataBase_OverCheck i RIGHT JOIN ( SELECT RTRIM(LTRIM(REPLACE(SUBSTRING(ipline, CHARINDEX(':', ipline) + 1, 20), '(首選)', ''))) AS 'ServerIP' FROM #tempserverip WHERE UPPER(ipline) LIKE '%IPv4 地址%'--這裡需要註意一下,系統不同這裡的匹配值就不同 AND UPPER(ipline) NOT LIKE '%192.168.%' AND UPPER(ipline) NOT LIKE '%169.254.%' ) p ON i.ServerIP = p.ServerIP ------ DECLARE IP CURSOR FOR SELECT ServerIP FROM dbo.DBA_ServerIPDataBase_OverCheck WHERE DisabledFlag IS NOT NULL AND DisabledFlag=0 OPEN IP FETCH NEXT FROM IP INTO @ip WHILE @@FETCH_STATUS = 0 BEGIN --SET @pingname = 'ping -a ' + @ip SET @pingname = 'ping -a ' + @ip + ' -n 1 -l 10' TRUNCATE TABLE #tempserverip INSERT #tempserverip EXEC master..xp_cmdshell @pingname SELECT @ServerName = REPLACE(RTRIM(LTRIM(SUBSTRING(ipline, 8, CHARINDEX('[', ipline) - 8))), '.XXXXXX.com', '') ,-----加域的電腦,電腦名字可能帶有功能變數名稱,請根據實際情況替換 @ServerFullName = RTRIM(LTRIM(SUBSTRING(ipline, 8, CHARINDEX('[', ipline) - 8))) FROM #tempserverip WHERE ipline LIKE '%正在 Ping%' UPDATE dbo.DBA_ServerIPDataBase_OverCheck SET ServerName = @ServerName , ServerFullName = @ServerFullName WHERE ServerIP = @ip FETCH NEXT FROM IP INTO @ip END CLOSE IP DEALLOCATE IP UPDATE dbo.DBA_ServerIPDataBase_OverCheck SET ServerIPType = 'Localhost' WHERE ServerName = @@SERVERNAME if OBJECT_ID('sys.availability_group_listener_ip_addresses') IS NOT NULL begin update a set a.ServerIPType='ListenIP' from DBA_ServerIPDataBase_OverCheck a inner join sys.availability_group_listener_ip_addresses b on a.ServerIP=b.ip_address end IF OBJECT_ID('sys.dm_hadr_cluster') IS NOT NULL BEGIN UPDATE dbo.DBA_ServerIPDataBase_OverCheck SET ClusterName=(SELECT cluster_name FROM sys.dm_hadr_cluster) UPDATE dbo.DBA_ServerIPDataBase_OverCheck SET ServerIPType='WindowsCluster' WHERE ServerName=(SELECT cluster_name FROM sys.dm_hadr_cluster) END IF OBJECT_ID('sys.dm_hadr_cluster') IS NULL BEGIN UPDATE dbo.DBA_ServerIPDataBase_OverCheck SET ClusterName='Not Cluster' END --0002 -20180530 針對20180530持續告警問題,發現告警時間超過預期,進行優化。聚焦點再表DBA_ServerIPDataBase_OverCheck中的CreateTime欄位,精準更新 begin UPDATE DBA_ServerIPDataBase_OverCheck SET DataBaseName=STUFF( (SELECT ',' + name FROM sys.databases WHERE name not in ('master' ,'tempdb','model','msdb','ReportServer','ReportServerTempDB','distribution') for xml path('') ), 1,1,'') -----002 end --the mail alarm declare @SQL as varchar(200) declare @Subject as varchar(200)=N'DB SERVER IP 有漂移,請檢查確認!' declare @Body as nvarchar(max)='' select @PreDiffDateTime= CreateTime from DBA_ServerIPDataBase_OverCheckOriginOrigin order by CreateTime SELECT TOP 0 A.* into #temp_DBA_ServerIPDataBase_OverCheck_diff FROM DBA_ServerIPDataBase_OverCheck A INNER JOIN DBA_ServerIPDataBase_OverCheckOriginOrigin B ON A.ServerIP =B.ServerIP IF EXISTS(SELECT * FROM DBA_ServerIPDataBase_OverCheck A LEFT JOIN DBA_ServerIPDataBase_OverCheckOriginOrigin B ON A.ServerIP =B.ServerIP WHERE B.ServerIP IS NULL) BEGIN INSERT INTO #temp_DBA_ServerIPDataBase_OverCheck_diff SELECT A.* FROM DBA_ServerIPDataBase_OverCheck A LEFT JOIN DBA_ServerIPDataBase_OverCheckOriginOrigin B ON A.ServerIP =B.ServerIP WHERE B.ServerIP IS NULL if exists( select * from #temp_DBA_ServerIPDataBase_OverCheck_diff ) begin set @Body= N'<html>' + N'<style type="text/css">' + N' td {border:solid #9ec9ec; border-width:1px 1px 1px 1px; padding:4px 0px;}' + N' table {border:1px solid #9ec9ec;width:80%;border-width:0px 0px 0px 0px;font-size:14px}' + N'</style>' + N'<H1 style="color:#FF0000;font-size:14px"></H1>' SET @Body=@Body+'<body><font color=#0000CC>Dear All,<br><br> 此List是監控到過去10 MIn Server IP 異常情況,'+@ServerIP +'伺服器有新IP創建聲明(新增), 請及時Check。具體數據如下:;<br><br><table>' SET @Body=@Body+'<tr bgcolor=#FFFF00 align="center"><td>ClusterName</td><td>ServerIP</td><td>ServerName</td><td>ServerIPType</td><td>DatabaseName</td><td>DisabledFlag</td><td>當前時間</td><td>差異採樣時間</td></tr>' SELECT @Body=@Body+'<tr><td>'+ClusterName+'</td><td>'+ServerIP+'</td><td>'+ServerName+'</td><td>'+ServerIPType+'</td><td>'+DatabaseName+'</td><td>'+ DisabledFlag+'</td><td>'+@CurrDateTime+'</td><td>'+ @PreDiffDateTime+'</td></tr>' from #temp_DBA_ServerIPDataBase_OverCheck_diff SET @Body = @Body +'</table><font color=#0000CC><br><br>DBA<br>Best wishes</body><html>' end END IF EXISTS(SELECT * FROM DBA_ServerIPDataBase_OverCheck A RIGHT JOIN DBA_ServerIPDataBase_OverCheckOriginOrigin B ON A.ServerIP =B.ServerIP WHERE A.ServerIP IS NULL) BEGIN DELETE FROM #temp_DBA_ServerIPDataBase_OverCheck_diff INSERT INTO #temp_DBA_ServerIPDataBase_OverCheck_diff SELECT A.* FROM DBA_ServerIPDataBase_OverCheck A RIGHT JOIN DBA_ServerIPDataBase_OverCheckOriginOrigin B ON A.ServerIP =B.ServerIP WHERE A.ServerIP IS NULL if exists( select