November 15, 2013 at 2:23 am
How can we get an email notification when db transaction log is full rather than production getting affected. it would be great any script available for the same
November 15, 2013 at 2:29 am
You can create a SQL Agent alert on the appropriate error message. You'll still have the effects of a full log on the DB though.
Why is your log filling often enough for this to be a concern?
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
November 18, 2013 at 5:33 am
This will alert you when the log usage gets to a certain %, this % amount is up to you.
CREATE procedure sqllogalert
@database varchar (20),
@threshold int
as
if not exists (select name from sys.databases where name = @database)
begin
print 'Database Does not Exist'
return
end
declare @server varchar(20)
declare @msgtext varchar (200)
declare @profile varchar (10)
set @server = @@servername
set @msgtext = 'SQL ALERT: Database '''+@database+''' On Server: '+@server+' - Transaction Log Usage Above Threshold'
set @profile = 'insert mail profile here'
if exists
(SELECT instance_name as [Database],
cntr_value as "LogFullPct"
FROM sys.dm_os_performance_counters
WHERE counter_name LIKE 'Percent Log Used%'
AND instance_name not in ('_Total', 'mssqlsystemresource')
AND instance_name = @database
and cntr_value > @threshold)
begin
exec msdb.dbo.sp_send_dbmail
@profile_name = @profile,
@recipients = 'insert recipients here',
@subject = @msgtext
end
else
begin
print 'Log File Ok'
end
Execute the procedure like this:
exec sqllogalert
@database = 'database_name'
,@threshold = threshold
Schedule it for as often as necessary
November 19, 2013 at 7:14 pm
Thanks a lot for sharing this script.is there option to consider disk space as well since my production log file growing because of full recovery mode.
November 19, 2013 at 10:32 pm
A properly maintained log should not be growing.
Please read through this: http://www.sqlservercentral.com/articles/Administration/64582/
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
November 21, 2013 at 5:46 am
As Gail pointed out, your log should not be growing. Proper sizing and regular log backups are vital.
Have a read through the link she posted.
If you need to monitor disk space you could look at xp_fixeddrives or sys.dm_os_volume_stats (2008 R2 and above).
November 22, 2013 at 5:44 am
Thanks a lot for your reply.we have implemented regular log backup and restricted that issue now.
Still we want to avoid log full situation if backup log is not working .Here My production database is running on 2005 version.is there any alternative way for this.
November 22, 2013 at 5:48 am
I would recommend you set up an alert for when log backups are not working. Something that checks when the last log backup was and alerts you if it's more than a certain time ago.
My focus would be to make sure that log backups are running.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply