SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Email Notification for Transaction log full


Email Notification for Transaction log full

Author
Message
amalanto
amalanto
SSC Journeyman
SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)

Group: General Forum Members
Points: 84 Visits: 166
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
GilaMonster
GilaMonster
SSC Guru
SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)

Group: General Forum Members
Points: 86479 Visits: 45238
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

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


SQLSACT
SQLSACT
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2078 Visits: 2931
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
amalanto
amalanto
SSC Journeyman
SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)

Group: General Forum Members
Points: 84 Visits: 166
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.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)

Group: General Forum Members
Points: 86479 Visits: 45238
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

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


SQLSACT
SQLSACT
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2078 Visits: 2931
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).
amalanto
amalanto
SSC Journeyman
SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)SSC Journeyman (84 reputation)

Group: General Forum Members
Points: 84 Visits: 166
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.
SQLSACT
SQLSACT
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2078 Visits: 2931
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.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search