I had someone ask me about using triggers to detect changes in their tables. This is the third post in the series. The first one
Another post for me that is simple and hopefully serves as an example for people trying to get blogging as #SQLNewBloggers.
The Setup
We’re using the same table from the first post. This is the dbo.Customer table with a PK and 5 other fields. Here is the data in the table:
I had this trigger in the last post, and showed how it captured updates to the ContactEmail field.
CREATE OR ALTER TRIGGER Customer_tru ON dbo.Customer FOR UPDATE
AS
BEGIN
IF UPDATE(CustomerName)
INSERT dbo.logger (logdate, logmsg) VALUES (DEFAULT, 'dbo.Customer.CustomerName changed')
IF UPDATE(AddressKey)
INSERT dbo.logger (logdate, logmsg) VALUES (DEFAULT, 'dbo.Customer.AddressKey changed')
IF UPDATE(CustomerStatus)
INSERT dbo.logger (logdate, logmsg) VALUES (DEFAULT, 'dbo.Customer.CustomerStatus changed')
IF UPDATE(CustomerContact)
INSERT dbo.logger (logdate, logmsg) VALUES (DEFAULT, 'dbo.Customer.CustomerContact changed')
IF UPDATE(ContactEmail)
BEGIN
INSERT dbo.logger (logdate, logmsg)
SELECT GETDATE(), 'ContactEmail updated from ' + d.ContactEmail + ' to ' + i.ContactEmail
FROM inserted i
INNER JOIN Deleted d ON i.CustomerID = d.CustomerID
END
END
This seemed to work, but did it really?
The Problem
Let’s illustrate the big problem with this change. I’ll run this code:
UPDATE dbo.Customer
SET ContactEmail = ‘andy@sqlservercentral.com’
WHERE CustomerID = 2;
If I do this, here are the results:
I get a NULL? Why, the original value is null and when I concatenate null with other values, I get NULL. Not ideal.
Let’s fix this problem. I’ll use a function to handle null values. Note, I need to do this for both the inserted and deleted tables. Here’s the new trigger.
CREATE OR ALTER TRIGGER Customer_tru ON dbo.Customer FOR UPDATE
AS
BEGIN
IF UPDATE(CustomerName)
INSERT dbo.logger (logdate, logmsg) VALUES (DEFAULT, 'dbo.Customer.CustomerName changed')
IF UPDATE(AddressKey)
INSERT dbo.logger (logdate, logmsg) VALUES (DEFAULT, 'dbo.Customer.AddressKey changed')
IF UPDATE(CustomerStatus)
INSERT dbo.logger (logdate, logmsg) VALUES (DEFAULT, 'dbo.Customer.CustomerStatus changed')
IF UPDATE(CustomerContact)
INSERT dbo.logger (logdate, logmsg) VALUES (DEFAULT, 'dbo.Customer.CustomerContact changed')
IF UPDATE(ContactEmail)
BEGIN
INSERT dbo.logger (logdate, logmsg)
SELECT GETDATE(), 'ContactEmail updated from ' + COALESCE(d.ContactEmail, 'null') + ' to ' + COALESCE(i.ContactEmail, 'null')
FROM inserted i
INNER JOIN Deleted d ON i.CustomerID = d.CustomerID
END
END
We can see this handles the null appropriately.
In this case I’ve chosen to replace a NULL value with the word ‘null’. This means something to me, but I could have just as well replaced this with “blank” or any other word. In many applications a developer might display a null value as a blank, so choose what works for you.
I’m also including an example to show this works for multiple rows. Here I’ll update multiple rows and we can see each is inserted into my log.
This is a good reason to audit certain activities, as people will sometimes make these mistakes and updates lots of data.
This trigger is slightly more useful, and handles the NULL cases, but it still isn’t perfect. Imagine I need to parse out changes, or generate the reverse transactions, or even search for certain changes. Stuffing a lot of data into a single field is overloading it, and making it less useful over time. What we’d really want to do is separate pertinent data into different fields. In a NoSQL world, we might do this by using a JSON schema to track the before and after.
We could do that here, just stuff JSON into the log message and read it back out and de-serialize it.
SQL New Blogger
This post modified our trigger to address a previous design problem: not handling nulls. We also showed how to test the trigger with multiple rows. This shows I’ve added knowledge to my skillset and can test what I’m trying to do.
Write your own blogs that might examine what you’ve done poorly in the past and how to fix the problems you’ve identified, even in simple code. Many of us do this a lot.
This was a 20-30 minute post for me. You could likely do it in a similar amount of time.