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


running trigger before deletion


running trigger before deletion

Author
Message
junk.mail291276
junk.mail291276
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: 2111 Visits: 120
Hello,

I have a table called Consequences. I have another table called RiskMatrixAxis. The Consequence table has several foreign key references to RiskMatrixAxis. I'm trying to settup a delete trigger on the RiskMatrixAxis to set the references in the Consequence table to null. Here's what it looks like:

CREATE TRIGGER [dbo].[trg_RiskMatrixAxis_ForDelete]
ON [dbo].[RiskMatrixAxis]
FOR DELETE
AS
BEGIN
UPDATE [dbo].[Consequence]
SET LikelihoodBeforeSafeguardId = NULL
WHERE LikelihoodBeforeSafeguardId in (SELECT RiskMatrixAxisId FROM deleted)
UPDATE [dbo].[Consequence]
SET LikelihoodAfterSafeguardId = NULL
WHERE LikelihoodAfterSafeguardId in (SELECT RiskMatrixAxisId FROM deleted)
UPDATE [dbo].[Consequence]
SET LikelihoodAfterRecommendationId = NULL
WHERE LikelihoodAfterRecommendationId in (SELECT RiskMatrixAxisId FROM deleted)

UPDATE [dbo].[Consequence]
SET SeverityBeforeSafeguardId = NULL
WHERE SeverityBeforeSafeguardId in (SELECT RiskMatrixAxisId FROM deleted)
UPDATE [dbo].[Consequence]
SET SeverityAfterSafeguardId = NULL
WHERE SeverityAfterSafeguardId in (SELECT RiskMatrixAxisId FROM deleted)
UPDATE [dbo].[Consequence]
SET SeverityAfterRecommendationId = NULL
WHERE SeverityAfterRecommendationId in (SELECT RiskMatrixAxisId FROM deleted)
END
GO


But this doesn't seem to work because the trigger only runs after the RiskMatrixAxis is deleted... which means the foreign keys in the Consequence table will not be set to null when the RiskMatrixAxis is delete, and therefore will throw an foreign key constraint error.

How can I get my trigger to run before the deletion actually happens?
ScottPletcher
ScottPletcher
SSC Guru
SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)

Group: General Forum Members
Points: 81462 Visits: 9184
You should seriously consider specifying "ON DELETE SET NULL" in the FK relationship and let SQL do this for you rather than writing it yourself.

SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
sgmunson
sgmunson
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: 86230 Visits: 6734
ScottPletcher - Tuesday, March 13, 2018 12:00 PM
You should seriously consider specifying "ON DELETE SET NULL" in the FK relationship and let SQL do this for you rather than writing it yourself.

Curiosity question... would using INSTEAD OF as opposed to FOR, and then ensuring no recursion, and then doing the delete yourself be a viable alternative when combined with your recommendation? Haven't had opportunity to work with FK delete scenarios as yet and am curious what experience you may have with that...


Steve
‌(aka sgmunson)
Smile Smile Smile
Health & Nutrition
ScottPletcher
ScottPletcher
SSC Guru
SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)

Group: General Forum Members
Points: 81462 Visits: 9184
sgmunson - Tuesday, March 13, 2018 12:17 PM
ScottPletcher - Tuesday, March 13, 2018 12:00 PM
You should seriously consider specifying "ON DELETE SET NULL" in the FK relationship and let SQL do this for you rather than writing it yourself.

Curiosity question... would using INSTEAD OF as opposed to FOR, and then ensuring no recursion, and then doing the delete yourself be a viable alternative when combined with your recommendation? Haven't had opportunity to work with FK delete scenarios as yet and am curious what experience you may have with that...

Yes, in theory you can do something like that. But then next week you add another table in the chain and you have to change the order of UPDATEs in your code again. I use context info settings to avoid trigger recursion conflicts when I need to, but I still prefer to let SQL do this automatically when it's applicable, i.e., when I want a key set to NULL rather than to prevent the parent DELETE from occurring (the default setting).


SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
sgmunson
sgmunson
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: 86230 Visits: 6734
ScottPletcher - Tuesday, March 13, 2018 12:40 PM
sgmunson - Tuesday, March 13, 2018 12:17 PM
ScottPletcher - Tuesday, March 13, 2018 12:00 PM
You should seriously consider specifying "ON DELETE SET NULL" in the FK relationship and let SQL do this for you rather than writing it yourself.

Curiosity question... would using INSTEAD OF as opposed to FOR, and then ensuring no recursion, and then doing the delete yourself be a viable alternative when combined with your recommendation? Haven't had opportunity to work with FK delete scenarios as yet and am curious what experience you may have with that...

Yes, in theory you can do something like that. But then next week you add another table in the chain and you have to change the order of UPDATEs in your code again. I use context info settings to avoid trigger recursion conflicts when I need to, but I still prefer to let SQL do this automatically when it's applicable, i.e., when I want a key set to NULL rather than to prevent the parent DELETE from occurring (the default setting).

Good reason! Might limit the applicability to very stable systems where change is concerned, but at least I now know a better alternative. Thank you, kind sir!


Steve
‌(aka sgmunson)
Smile Smile Smile
Health & Nutrition
junk.mail291276
junk.mail291276
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: 2111 Visits: 120

ON DELETE SET NULL only works if you set it on one of them. Otherwise you get this error:

"Introducing FOREIGN KEY constraint 'FK_Consequence_RiskMatrixAxis_LikelihoodAfterSafeguard' on table 'Consequence' may cause cycles or multiple cascade paths."

I'll try the INSTEAD OF DELETE option and get back to you.


junk.mail291276
junk.mail291276
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: 2111 Visits: 120
INSTEAD OF DELETE seems to work for my purposes.
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