running trigger before deletion

  • 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?

  • 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) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".

  • 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) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)

  • 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) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".

  • 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) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)

  • 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.

  • INSTEAD OF DELETE seems to work for my purposes.

Viewing 7 posts - 1 through 6 (of 6 total)

You must be logged in to reply to this topic. Login to reply