Monitoring scheduled backup jobs

  • Good afternoon,

    Apologies for this long post but I would really appreciate some feedback on my approach to solving the following problem of monitoring backups. This process will need to monitor database backups on 28 SQL Servers but for the time being I would like to get the process working for 1 server.

    Current setup:

    1 SQL Server - 10 Databases

    Backup schedule: Fortnightly full backups + nightly differentials.

    Full backups:

    There is an unscheduled SQL Agent job setup on each SQL Server instance which is manually run by our IT manager every 2 weeks. This job loops through the list of databases and does a full backup of each one.

    Differentials:

    Scheduled job on each SQL Server instance which runs every day at midnight.

    Unfortunately DB mail is disabled on ALL servers and due to security reason. So I’m unable to use notifications to send mail if the backup job fails.

    Solving the problem:

    1) Schedule the full backup jobs to run every two weeks on Saturdays at 6PM and the daily diffs to run at midnight every day.

    2) Setup a utilities server which I will use to hold my DBA repository, this will have SQL Server DB engine + SSIS + SSRS installed on it.

    3)Trigger a scheduled job on my utilitties server to run at 8AM every morning to check for database backups from the last 24 hours. If there no rows returned then trigger an email notification. (I will enable DB mail on this utilities server).

    4) Trigger another scheduled job to gather information about the previous days backup, this will be information like backup start and end time, backup size, duration etc..

    Any advice would be much appreciated.

    Thanks.

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

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • First, I'd make sure you are copying those full backups around to other places. If you lose one of them, you don't want to be going back a month or more. If you are going to let them keep you safe for 2 weeks, take extra precautions.

    Can you use Service Broker? If so, forward notifications of issues through a queue to another server that can send you a note if you need to restart a backup when it fails. If you can let it go until the morning, don't worry so much about notifications.

    I wouldn't use a central server to call all these jobs. If it has issues, and it will, you may end up missing notifications. The thing I've found when doing this is that at some point your central server will query server 1, then server 2, then fail. If you haven't accounted for that somehow, you might not realize that servers 3 and 4 were never checked.

    The way I've done this is I have every server monitor itself. Make a small db (worst case, stick some tables in msdb) and query for backup status, jobs status each day. Store that information at each server. Make this a part of build status. I went so far as you also make a "report" table that merely stored the day's reports in a series of rows I could easily read with a query.

    Then have a central server that has a list of all servers you need to monitor. Use that as a way to go get the report (or data) from each individual server. when you build your report, make sure you have a join with your central list and if there are missing servers, flag that.

    I'd also make sure that I showed exceptions first, and then all the data. If you just show the data, it's easy to miss issues, especially over time and at scale.

  • Thanks for the advice Steve. Please see my comments below:

    The way I've done this is I have every server monitor itself. Make a small db (worst case, stick some tables in msdb) and query for backup status, jobs status each day. Store that information at each server. Make this a part of build status. I went so far as you also make a "report" table that merely stored the day's reports in a series of rows I could easily read with a query.

    Just to clarify:

    1) Create a scheduled job on each server to gather information about job and backup statuses and store them in a localdb or as you said, worst case, a couple of tables in MSDB.

    2) Create an SSIS package on the central server that will loop through the list of servers to poll the backup information and store it in the central database for reporting purposes.

    Sorry but I’m confused as to why the need for the local data on each server? Why not get the information straight from the MSDB as my SSIS package loops through each one?

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

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • If you central server is down, where is the data on backups? If your package has a bug, or can't connect to an instance, what happens to the data?

  • Steve Jones - SSC Editor (9/21/2012)


    If you central server is down, where is the data on backups? If your package has a bug, or can't connect to an instance, what happens to the data?

    I understand what you mean. My only worry is the business will not allow me to setup these tables on each server. It was a struggle just to get them to agree to allow me to change the backup sproc so the master DB is also included.

    But what you say is true. If the central server is down or unable to communicate with the other servers for whatever reason then the DBA who gets the reports will think that no backups were run the night before!

    This is trickier than I thought.......

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

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • Hi,

    This code helps me keep track of what's being backed up, and more importantly, what is not.

    You'll need a DB and table to store the data in.

    ALTER PROCEDURE [dbo].[usp_GetSvrDBBackups] @svr Varchar(50), @DB Varchar(50), @TopN TinyInt = 1

    AS

    SET NOCOUNT ON

    --DECLARE @svr Varchar(50), @DB Varchar(50), @TopN TinyInt

    --SET @svr = 'Server1\Instance2'

    --SET @DB = 'DBADB'

    --SET @TopN = 5

    DECLARE @SQL Varchar(MAX)

    -- Get rid of the old data.

    DELETE FROM AllBackups WHERE SvrName = @svr AND DBName = @DB

    /*

    Backup Types:

    L = Log

    D = Full

    I = Differential

    */

    SET @SQL = '

    INSERT INTO AllBackups (SvrName, DBName, BackupSize, BackupStart, BackupFinish, BackupType, DeviceName, Server_Name)

    SELECT TOP ' + CAST(@TopN AS Varchar) + ' ''' + @svr + ''', BS.Database_name, BS.backup_size, BS.backup_Start_date, backup_finish_date,

    BS.type, BMF.Physical_Device_Name, BS.Server_Name

    FROM [' + @svr + '].MSDB.DBO.BackupSet BS

    INNER JOIN [' + @svr + '].MSDB.DBO.BackupMediaFamily BMF ON BS.Media_Set_ID = BMF.Media_Set_ID

    WHERE Type = ''D''

    AND Database_name = ''' + @DB + '''

    ORDER BY backup_finish_date DESC

    INSERT INTO AllBackups (SvrName, DBName, BackupSize, BackupStart, BackupFinish, BackupType, DeviceName, Server_Name)

    SELECT TOP ' + CAST(@TopN AS Varchar) + ' ''' + @svr + ''', BS.Database_name, BS.backup_size, BS.backup_Start_date, backup_finish_date,

    BS.type, BMF.Physical_Device_Name, BS.Server_Name

    FROM [' + @svr + '].MSDB.DBO.BackupSet BS

    INNER JOIN [' + @svr + '].MSDB.DBO.BackupMediaFamily BMF ON BS.Media_Set_ID = BMF.Media_Set_ID

    WHERE Type = ''L''

    AND Database_name = ''' + @DB + '''

    ORDER BY backup_finish_date DESC

    INSERT INTO AllBackups (SvrName, DBName, BackupSize, BackupStart, BackupFinish, BackupType, DeviceName, Server_Name)

    SELECT TOP ' + CAST(@TopN AS Varchar) + ' ''' + @svr + ''', BS.Database_name, BS.backup_size, BS.backup_Start_date, backup_finish_date,

    BS.type, BMF.Physical_Device_Name, BS.Server_Name

    FROM [' + @svr + '].MSDB.DBO.BackupSet BS

    INNER JOIN [' + @svr + '].MSDB.DBO.BackupMediaFamily BMF ON BS.Media_Set_ID = BMF.Media_Set_ID

    WHERE Type = ''I''

    AND Database_name = ''' + @DB + '''

    ORDER BY backup_finish_date DESC'

    --PRINT @SQL

    EXEC (@SQL)

    --SELECT * FROM AllBackups

    EXEC usp_Upt_Refreshed @svr = @svr, @DB = @DB, @Cat = 'Backups'

    You can then cycle through your servers easily with : (I have a table with all database and server names. (AllDBs)

    ALTER PROCEDURE [dbo].[usp_GetAllServerBackups]

    AS

    SET NOCOUNT ON

    DECLARE @svr Varchar(50), @DB Varchar(50)

    --SET @svr = 'Server\Instance'

    --SET @DB = 'TestDB'

    DECLARE cSvrs Cursor FOR SELECT DISTINCT SvrName, DBName FROM AllDBs

    OPEN cSvrs

    FETCH NEXT FROM cSvrs INTO @svr, @DB

    WHILE @@FETCH_STATUS = 0

    BEGIN

    EXEC usp_GetSvrDBBackups @svr = @svr, @DB= @DB, @TopN = 1

    FETCH NEXT FROM cSvrs INTO @svr, @DB

    END

    CLOSE cSvrs

    DEALLOCATE cSvrs

    Using a central table with all database and servers allows you to create code to pull out and store anything you need. E.g. Tables, Columns, Jobs, Triggers, SPs etc...

    Your central server will need linked servers to each of your servers you want monitor.

    ( SELECT TOP 1 * FROM sys.Servers. make sure is_Linked = 1 otherwise you will encounter irritating problems.)

    Hope this points you in the right direction.

    Goodluck.



    For better, quicker answers on T-SQL questions, read Jeff Moden's suggestions.[/url]

    "Million-to-one chances crop up nine times out of ten." ― Terry Pratchett, Mort

  • D.Post, Thank you very much for this. Very useful indeed!

    I've got my Utilities Server setup with SQL Server 2008 installed on it and I've just setup my DBA Repository database.

    Now it's time to create the necessary objects and setup my SSIS package to do the work.

    Will provide another update in a few days’ time.

    Cheers.

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

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

Viewing 7 posts - 1 through 6 (of 6 total)

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