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


Trigger with RAISERROR


Trigger with RAISERROR

Author
Message
PiMané
PiMané
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1024 Visits: 1334
Hi,

Why doesn't a RAISERROR inside an AFTER trigger "break" the transaction? Is there any flag or SET option to do it?
I created a table with a trigger that just has RAISERROR and the UPDATE is executed any way...

CREATE TABLE test (ID INT NOT NULL, Val INT);
GO
INSERT INTO test VALUES (1,1), (2,2), (3,3);
GO
CREATE TRIGGER trg_test_upd ON test AFTER UPDATE
AS
RAISERROR('Error', 16, 1)
GO


If I execute:

SELECT * FROM test
BEGIN TRAN
UPDATE test SET val = 3 WHERE id = 1
COMMIT TRAN
SELECT * FROM test


The update is committed even with the error raised from the trigger.
The only way it isn't committed is if I have error handling:

SELECT * FROM test
BEGIN TRAN
BEGIN TRY
UPDATE test SET val = 3 WHERE id = 1
COMMIT TRAN
END TRY
BEGIN CATCH
ROLLBACK TRAN
END CATCH
SELECT * FROM test





If you need to work better, try working less...
Sean Pearce
Sean Pearce
SSCommitted
SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)

Group: General Forum Members
Points: 1774 Visits: 3432
You need to use ROLLBACK inside the trigger.

CREATE TRIGGER trg_test_upd ON test AFTER UPDATE
AS
RAISERROR('Error', 16, 1);
ROLLBACK;
GO





The SQL Guy @ blogspot

@SeanPearceSQL

About Me
Sean Pearce
Sean Pearce
SSCommitted
SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)

Group: General Forum Members
Points: 1774 Visits: 3432
The behavior is the same with a stored proc

CREATE TABLE test (ID INT NOT NULL, Val INT);
GO
INSERT INTO test VALUES (1,1), (2,2), (3,3);
GO
CREATE PROCEDURE trg_test_upd
AS
UPDATE test SET val = 3 WHERE id = 1
RAISERROR('Error', 16, 1);
GO



SELECT * FROM test
BEGIN TRAN
EXEC trg_test_upd
COMMIT TRAN
SELECT * FROM test





The SQL Guy @ blogspot

@SeanPearceSQL

About Me
PiMané
PiMané
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1024 Visits: 1334
Thanks,

Thought that the XACT_ABORT should solve it but it doesn't.



If you need to work better, try working less...
lshanahan
lshanahan
SSChasing Mays
SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)

Group: General Forum Members
Points: 622 Visits: 436
PiMané (9/30/2013)
Hi,

Why doesn't a RAISERROR inside an AFTER trigger "break" the transaction? Is there any flag or SET option to do it?

The update is committed even with the error raised from the trigger.
The only way it isn't committed is if I have error handling:



RAISERROR simply tells SQL Server where to transfer control or send a message based on where it is in your code and the severity level of the error. From BOL:


When RAISERROR is run with a severity of 11 or higher in a TRY block, it transfers control to the associated CATCH block. The error is returned to the caller if RAISERROR is run:

Outside the scope of any TRY block.

With a severity of 10 or lower in a TRY block.

With a severity of 20 or higher that terminates the database connection.


RAISERROR doesn't "break" a transaction simply because you may not need to do so. You may encounter issues that have nothing to do with data integrity where you just want to return something to the caller as a warning (say, an inventory level is approaching some minimum value) yet let the transaction commit normally. BOL indicates RAISERROR can be used as a substitute for the print statement because you can use C-style printf character substitution, which print won't do.

There's probably more nuances than that (I'll let the real pros comment on that) but I believe that is the essential nugget.

____________
Just my $0.02 from over here in the cheap seats of the peanut gallery - please adjust for inflation and/or your local currency.
e.alakhras
e.alakhras
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 11
Perhaps better to rollback before raiserror.
You don't know what an error handler would do, especially time wise.
Releasing a transaction at the earliest will release locks, thus, wait at other connections.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)

Group: General Forum Members
Points: 87269 Visits: 45272
Please note: 3 year old thread.

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


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