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


TRIGGER AFTER DELETE question


TRIGGER AFTER DELETE question

Author
Message
Matt Toynbee
Matt Toynbee
SSC Rookie
SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)

Group: General Forum Members
Points: 40 Visits: 49
I have a delete trigger but I want to email me the username field value that has been deleted. Is this possible - if so how?

Sample code:



CREATE TRIGGER delUsers
ON db_users
AFTER DELETE
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
EXECUTE
MSDB.dbo.sp_send_dbmail @profile_name = 'Mail Profile 1'
, @recipients = 'me@email.co.uk'
, @copy_recipients = ''
, @blind_copy_recipients = ''
, @SUBJECT = 'User Deleted'
, @body = 'User Deleted'
, @body_format = 'HTML'
, @importance = 'Normal'
, @sensitivity = 'Normal'

END
GO



sanoj_av2001
sanoj_av2001
SSC Journeyman
SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)

Group: General Forum Members
Points: 91 Visits: 119
CREATE TRIGGER delUsers ON db_users AFTER DELETE
AS
BEGIN
SET NOCOUNT ON
Declare
@User_name varchar(100),
@body varchar(100)
Select @User_name=usrname from deleted
Set @body='User ' +@User_name+ ' Deleted'
EXEC msdb.dbo.sp_send_dbmail
@profile_name = 'Mail Profile 1',
@recipients = 'me@email.co.uk',
@body = @body,
@subject ='User Deletion'
END

--Where usrname is the field in your table db_users

..
Matt Toynbee
Matt Toynbee
SSC Rookie
SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)

Group: General Forum Members
Points: 40 Visits: 49
Thanks a million - works great!
Jack Corbett
  Jack Corbett
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45919 Visits: 14925
Matt Toynbee (5/6/2009)
Thanks a million - works great!


Actually it only works great if you have single row delete. If you have a batch delete occur you will only get one email sent out and you cannot be guaranteed which row will be the one you alerted about.

For example if I run this code:


Delete
From
db_users
Where
UserName Like 'A%'



You will get only 1 email.

In my opinion, you really should stage the deleted data in a table and then have a job that reads that table and sends you an email or multiple emails. Or you could use SSRS and create an email subscription that sends you an email with deleted users in the last N minutes/hours.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
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