Today I decided to revisit the post about coding triggers for multi-row operations
There are many forum posts and questions on stackoverflow where people have trigger code. However these triggers are coded incorrectly because they don't account for multi-row operations.
The one thing you have to remember is that a trigger fires per batch not per row, if you are lucky you will get an error...if you are not lucky you will not get an error but it might take a while before you notice that you are missing a whole bunch of data
Let's take a look at exactly what happens, first create these two tables
CREATE TABLE Test(id int identity not null primary key, SomeDate datetime not null) GO CREATE TABLE TestHistory(id int not null, InsertedDate datetime not null) GO
Now create the following trigger.
CREATE TRIGGER trTest ON Test FOR INSERT AS IF @@ROWCOUNT =0 RETURN DECLARE @id int SET @id = (SELECT id FROM inserted) INSERT TestHistory (id,InsertedDate) SELECT @id, getdate() GO
The trigger you just created is very simple, it basically inserts a row into the history table every time an insert happens in the test table
Run this insert statement which only inserts one row
INSERT Test(SomeDate) values(getdate())
Now run this to see what is in the history table
SELECT * FROM TestHistory
1 2017-10-14 08:49:16.227
That all works fine, what happens when we try to insert 2 rows?
INSERT Test(SomeDate) SELECT getdate() UNION ALL SELECT dateadd(dd,1,getdate() )
Here is the error.
Server: Msg 512, Level 16, State 1, Procedure trTest, Line 11
Subquery returned more than 1 value. This is not permitted when the subquery follows =, !=, <, <= , >, >= or when the subquery is used as an expression.
The statement has been terminated.
As you can see the trigger blew up with an error. Let's try something else.
What would happen if you coded the trigger in this way
ALTER TRIGGER trTest ON Test FOR INSERT AS IF @@ROWCOUNT =0 RETURN DECLARE @id int SELECT @id = id FROM inserted INSERT TestHistory (id,InsertedDate) SELECT @id, getdate() GO
Now insert one row
INSERT Test(SomeDate) VALUES (getdate())
We look again what is in the history table, as you can see we have id 1 and 4, this is because id 2 and 3 failed and were rolled back when we did the insert earlier
SELECT * FROM TestHistory
1 2017-10-14 08:49:16.227
4 2017-10-14 08:50:37.647
Here is where it gets interesting, run this code
INSERT Test(SomeDate) SELECT getdate() UNION ALL SELECT dateadd(dd,1,getdate() )
That runs fine but when we look now we are missing one of the rows in the history table
SELECT * FROM TestHistory
1 2017-10-14 08:49:16.227
4 2017-10-14 08:50:37.647
5 2017-10-14 08:51:06.270
let's try that same insert statement again
INSERT Test(SomeDate) SELECT getdate() UNION ALL SELECT dateadd(dd,1,getdate() )
Now we are again missing a row in the history table
SELECT * FROM TestHistory
1 2017-10-14 08:49:16.227
4 2017-10-14 08:50:37.647
5 2017-10-14 08:51:06.270
7 2017-10-14 08:52:09.447
The problem is with this line of code
SELECT @id = id FROM inserted
@id will only hold the value for one of the rows that was returned in the result set
Here is how you would change the trigger to work correctly
ALTER TRIGGER trTest ON Test FOR INSERT AS IF @@ROWCOUNT =0 RETURN INSERT TestHistory (id,InsertedDate) SELECT id, getdate() FROM inserted GO
Now run the single insert statement again
INSERT Test(SomeDate) VALUES (getdate())
That row was inserted, we can check the history table to see what is there now
SELECT * FROM TestHistory
1 2017-10-14 08:49:16.227
4 2017-10-14 08:50:37.647
5 2017-10-14 08:51:06.270
7 2017-10-14 08:52:09.447
9 2017-10-14 08:52:57.990
Finally, we can again test with the insert statement that will insert 2 rows
INSERT Test(SomeDate) SELECT getdate() UNION ALL SELECT dateadd(dd,1,getdate() )
Let's check the history table again
SELECT * FROM TestHistory
1 2017-10-14 08:49:16.227
4 2017-10-14 08:50:37.647
5 2017-10-14 08:51:06.270
7 2017-10-14 08:52:09.447
9 2017-10-14 08:52:57.990
11 2017-10-14 08:53:40.693
10 2017-10-14 08:53:40.693
And as you can see both rows were inserted into the history table
So what is worse in this case? The error message or the fact that the code didn't blow up but that the insert wasn't working correctly? I'll take an error message any time over the other problem.