December 4, 2012 at 1:09 pm
Dear Forum,
I'm sure someone has completed this type of request, but here is the back ground.
I have a thrid party tool to complete all forms of backups on SQL databases. I have recently found that from time to time this 3rd party backup tool will drop a backup schdule. For example I have a instance where Transaction Log backups have not occured in months. So now I must Mirco manage the backups across some 600 instances.
My questions does any have the code or an example on how send or create an alert if a database has not had a log backup with in the last 24 hours?
All Enviroments are either 2K8 or 2K8R2.
Any help or direction would be gladly execpted.
Fishing for help..:hehe:
December 4, 2012 at 2:53 pm
-- GET DATABASES WITHOUT FULL OR TLOG BACKUPS
-- dbs with no full backups in last week
(select cast(a.[name] as varchar(100)) as db_nm into #no_full_backup
from master.dbo.sysdatabases a
left join msdb.dbo.backupset b
on a.[name] = b.database_name and datediff(hour,b.backup_finish_date,getdate())<168 -- 1 week
and b.type='D'
where a.[name] != 'tempdb'
and databasepropertyex(a.[name], 'isinstandby') = 0
and databasepropertyex(a.[name], 'status') = 'online'
and databasepropertyex(a.[name], 'updateability') = 'read_write'
and b.database_name is null )
-- dbs with no transaction log backup for a day
(select cast(a.database_name as varchar(100)) as db_nm into #no_tlog_backup
from
(
select [name] as database_name
from master.dbo.sysdatabases
where databasepropertyex([name], 'recovery') in ('FULL','BULK_LOGGED')
and databasepropertyex([name], 'isinstandby') = 0
and databasepropertyex([name], 'status') = 'online'
and databasepropertyex([name], 'updateability') = 'read_write'
and [name] not in ('model','tempdb')
) a
left join msdb.dbo.backupset b
on a.database_name = b.database_name and b.type='L' and datediff(hour,b.backup_finish_date,getdate())<24
where b.database_name is null)
--select * from #no_full_backup
--select * from #no_tlog_backup
if (select count(*) from #no_full_backup) > 0
raiserror ('databases with no full backups in last 7 days exist',16,1) with log
if (select count(*) from #no_tlog_backup) > 0
raiserror ('databases with no transaction backups in last 1 days exist',16,1) with log
drop table #no_full_backup
drop table #no_tlog_backup
This one is actually SQL2000 compatible but works on other versions. You would be well to get the database status values from table master.sys.databases
---------------------------------------------------------------------
December 4, 2012 at 3:03 pm
to expand on what george posted you can create a procedure and schedule an agent job to run it. the procedure would also email the results (if any) using sp_send_dbmail http://msdn.microsoft.com/en-us/library/ms190307.aspx
im currently working on some example code and will post when im done
EDIT:
Here is a rough sample and will probably need to be tweaked to make it work specifically as you want so it will email you through the dbmail system if there is an error. you would just set up an agent job to run the SP once a day
CREATE PROCEDURE usp_NoTlogBackup (@Length INT)
AS
DECLARE @BadDatabases VARCHAR(8000)
DECLARE @Body VARCHAR(8000)
SELECT @BadDatabases = STUFF(
(select ', ' + cast(a.database_name as varchar(100))
from
(
select [name] as database_name
from master.dbo.sysdatabases
where databasepropertyex([name], 'recovery') in ('FULL','BULK_LOGGED')
and databasepropertyex([name], 'isinstandby') = 0
and databasepropertyex([name], 'status') = 'online'
and databasepropertyex([name], 'updateability') = 'read_write'
and [name] not in ('model','tempdb')
) a
left join msdb.dbo.backupset b
on a.database_name = b.database_name
and b.type='L'
and datediff(hour,b.backup_finish_date,getdate()) < @Length
where b.database_name is null
FOR XML PATH ('')
),1,2,'')
IF (@BadDatabases IS NOT NULL)
BEGIN
SET @Body = 'On ' + @@SERVERNAME + ' The following Databases do not have Tlog backups: ' + @BadDatabases
EXEC msdb.dbo.sp_send_dbmail @profile_name = 'profile_name',
@recipients = 'your@email.com',
@from_address = 'ServerName@from.com',
@body = @Body
END
For performance Issues see how we like them posted here: How to Post Performance Problems - Gail Shaw[/url]
Need to Split some strings? Jeff Moden's DelimitedSplit8K[/url]
Jeff Moden's Cross tab and Pivots Part 1[/url]
Jeff Moden's Cross tab and Pivots Part 2[/url]
December 4, 2012 at 3:20 pm
we actually schedule our check via SCOM, so if you have an enterprise monitoring tool like SCOM you would hopefully be able to plug the script into it.
---------------------------------------------------------------------
December 4, 2012 at 5:12 pm
Have a look at Policy Based Management.
I set my policies up as "On Demand", and schedule the evaluations from a Central Management Server. This allows me to check my 2005 servers as well.
But as you say all your servers are 2008+, you could create them with "On Schedule" evaluation modes so that each instance checks itself regularly. A failure results in an error in the log, which can be alerted on using a SQL Agent Alert.
http://msdn.microsoft.com/en-us/library/bb510667(v=sql.105).aspx
December 5, 2012 at 6:50 am
Thank you everyone for your fast response and code posting, now with a quit afternoon(not likely). I can get this loaded throughout my universe.
December 5, 2012 at 8:08 am
Out of curiosity can you post which solution you used once you get one in place?
For performance Issues see how we like them posted here: How to Post Performance Problems - Gail Shaw[/url]
Need to Split some strings? Jeff Moden's DelimitedSplit8K[/url]
Jeff Moden's Cross tab and Pivots Part 1[/url]
Jeff Moden's Cross tab and Pivots Part 2[/url]
September 19, 2013 at 12:34 pm
Sorry for the late response to your request to know which code set I used. The answer is sorry none, part of process are in ultra secure enviroments and server level email would be a strict no-no, and would case what is known as a Resume generating event(RGE).
and are instances have grown to 1300 since this posting.
the final process was a set of SSIS packages that collected requested information, and then we are using SSRS to allow management and application owners to see what is happening. it is crude but meets the need.
Thank you for the information.
September 19, 2013 at 12:50 pm
i do this with Powershell. Job runs every morning, and checks to see if a backup, full or differential, has been run in the last 24 hours. Also checks to see if a full backup is more than a week old, in case we are running differentials instead of full backup. it also checks to see if the db has FULL recovery, and if so, checks to see if the transaction log is more than 24 hours old. Loops through all of my servers, and then emails if backup is old or if it can't connect to a server. i have attached a zip file, with the Powershell code. this version is used to run from a SQL Agent job. You will need to update how the servers are retrieved. i put them in a table.
Only the server that runs the report needs to have ability to smtp.
You also need to make sure your job can connect to all of your other servers. i have a proxy set up to do that.
Leonard
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply