Automatic Alert Generation in the event of SQL Server Cluster Failover

  • Comments posted to this topic are about the item Automatic Alert Generation in the event of SQL Server Cluster Failover

  • What if a failover occurs but the other node fails to come online and it fails back to the original server? No alert will be raised.

    What if the cluster shuts down and can't start on either node? No alert will be raised.

    You need to monitor externally.


    My blog: SQL Soldier[/url]
    SQL Server Best Practices:
    SQL Server Best Practices
    Twitter: @SQLSoldier
    My book: Pro SQL Server 2008 Mirroring[/url]
    Microsoft Certified Master: SQL Server, Data Platform MVP
    Database Engineer at BlueMountain Capital Management[/url]

  • I am using a similar approach, but outside the monitored clustered SQL Server. I have added an external application (a .CMD file) as a clustered resource. It uses a SQLCMD script that uses a different instance of SQL server to send an email about the status change:

    SQLCMD /S <servername> /E /i M:\ClusterMonitor\ResourceChangeNotification.sql >> M:\ClusterMonitor\ResourceChangeMonitorLog.txt

    It still depends on that instance to send notifications and it only looks at SQL Server group (we're also clustering DTC). So I'm not 100% happy with this. But I wasn't able to find any other workaround for this. Are there any tools to monitor for status changes of a clustered resource: goes offline, comes online, cannot be brought online, etc.

    I am interested in a solution that will also indicate the resource affected by the change, what the change was, etc. Does anyone know of such a solution ?

    Thanks.

    Regards,

    Alin

  • I'm using a SQL Agent Job with the Schedule: "Start automatically when SQL Server Agent starts"

    With the following T-SQL Script

    DECLARE @SRV VARCHAR(64)

    DECLARE @INST VARCHAR(64)

    DECLARE @MBODY VARCHAR(255)

    DECLARE @SUBJ VARCHAR(255)

    SELECT @SRV=CAST(SERVERPROPERTY('ComputerNamePhysicalNetBIOS') AS VARCHAR)

    SELECT @INST=@@servername

    SET @MBODY = 'Active Node for ' + @INST + ' is ' + @SRV

    SET @SUBJ = '!!!ALERT!!! - ' + @SRV + ' restarted'

    EXEC msdb.dbo.sp_send_dbmail

    @profile_name = 'DBMAIL',

    @recipients = 'mail@domain.com',

    @body = @MBODY,

    @subject = @SUBJ;

    Bye

  • I'm using that as well, in conjuction with what I already mention, but this is still internal and relies on SQL server services to be successfully brought online.

  • Certainly an out of the box method to be notified of a failover. As mentioned it has some issues, but certainly could be part of an overall plan. I don't have experience dealing with clusters, but I do like the method provided by Tim Ford over at msssqltips, http://www.mssqltips.com/sqlservertip/1663/auto-notification-for-failover-of-a-server-and-restart-of-sql-server-services/ a little better.

  • This is good information.

    I've always created a job that would inform me when SQL Server services were restarted and it has served me well.

    I have the job send an email to a key group:

    EXEC msdb.dbo.sp_send_dbmail

    @recipients='dbadmin@oursite.net',

    @profile_name = 'Production Database Mail',

    @subject = 'SQL Services Restarted on Production DB',

    @body = 'Services restarted, possible cluster failover'

    Schedule type = "Start automatically when SQL Server Agent starts"

    I know its not exactly when a failover happens but I like to know when the services are restarted or the machine is booted anyway.

  • What kind of performance impact is involved if scheduled to run every seconds in SQL2008 R2 enviroinment or scheduled to run every minute in SQL2005 enviroinment.

    This job queries registry parameters will that prove a problem to performance.

    BR

    Eben

  • Hello,

    About getting the node where the instance is running, you can use the following query:

    select Nodename from sys.dm_os_cluster_nodes

    or this other one:

    select Nodename from ::fn_virtualservernodes()

    The query above would give you the names of the nodes on that cluster, and it will list first the active node for that instance... just add a TOP 1 and your are golden without having to access the registry.

  • Thanks, its useful information.

    Coming to the main article where the Author speaks about scheduling the job as a SQL agent job for every minutes or seconds, will that cause any performance impact to the DB engine utilization..

    BR

    Eben

  • Thanks for this article. I have used it and placed it on my SQL clusters.

    I took it a step further and created another table.

    ClusterFailoverHistory

    CREATE TABLE [dbo].[ClusterFailoverHistory](

    [PreviousActiveNode] [varchar](30) NULL,

    [CurrentActiveNode] [varchar](30) NULL,

    [LastUpdated] [datetime] NULL

    ) ON [PRIMARY]

    In your original code, I creaeted one more line after the final update.

    I insert the history of the failover having occurred.

    update CLUSTERFAILOVERMONITOR set PREVIOUS_ACTIVE_NODE=@VAR2

    Insert into ClusterFailoverHistory

    Select @VAR1, @var2, GETDATE()

  • We just added the proc below to master, works like a charm:

    CREATE PROCEDURE [dbo].[sp_PageClusterHostname]

    AS

    DECLARE @p_hostname VARCHAR(500)

    DECLARE @v_hostname VARCHAR(500)

    DECLARE @STR VARCHAR(1000)

    SELECT @v_hostname = @@ServerName + ' SQL Server Restarted'

    SELECT @p_hostname = CONVERT(VARCHAR(100),SERVERPROPERTY('ComputerNamePhysicalNetBios'))

    SELECT @STR = @v_hostname + ' and running on ' + @p_hostname + ' Physical Server'

    EXECUTE msdb.dbo.sp_notify_operator

    @profile_name = 'CorpDBMail',

    @name=N'PrimaryDBA',

    @subject = @v_hostname,

    @body=@STR

    GO

    EXEC sp_procoption N'[dbo].[sp_PageClusterHostname]', 'startup', '1'

    GO

  • Jack Corbett (10/6/2011)


    Certainly an out of the box method to be notified of a failover. As mentioned it has some issues, but certainly could be part of an overall plan. I don't have experience dealing with clusters, but I do like the method provided by Tim Ford over at msssqltips, http://www.mssqltips.com/sqlservertip/1663/auto-notification-for-failover-of-a-server-and-restart-of-sql-server-services/ a little better.

    I concur, firing an alert when the service starts is probably the best way

    -----------------------------------------------------------------------------------------------------------

    "Ya can't make an omelette without breaking just a few eggs" 😉

  • Robert Davis (10/5/2011)


    What if a failover occurs but the other node fails to come online and it fails back to the original server? No alert will be raised.

    What if the cluster shuts down and can't start on either node? No alert will be raised.

    You need to monitor externally.

    Robert is right. You need to put monitoring program on reliable "node3".

    If your polling interval is too long, conditions can happen but not detected. Inexpensive implementation solution for low SLA requirements.

    Regards,

    Jason

    http://usa.redirectme.net

  • Sir,

    Good Morning.

    Great article. I've been searching for a procedure like this for awhile !

    A suggestion:

    The constant creation and dropping of table PHYSICALHOSTNAME against the master database has the potential for causing master database fragmentation, as well as corruption.

    I made table PHYSICALHOSTNAME a virtual table, ie,

    CREATE TABLE #PHYSICALHOSTNAME

    and so forth....

    Thanks !

Viewing 15 posts - 1 through 14 (of 14 total)

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