October 2, 2012 at 4:30 am
Hi
I'm looking at using Merge which I've never used. I've achieved Auditing before with an After trigger that writes the old row to the audit table. I'm only interested in writting to the audit table if the values change so use checksum.
create table tblCustomer
(CID int not null primary key,
name varchar(10) not null,
country varchar(15) not null)
insert into tblCustomer values (1, 'Bob', 'UK'), (2, 'Claire', 'USA'), (3,'Terry','France')
create table tblUpdates
(
CID int not null,
name varchar(10) not null,
country varchar(15) not null
)
insert into tblUpdates values (1, 'Bob', 'UK'), (2, 'Claire', 'Mexico'), (3,'Terrance','Spain'),(4,'Abdul','Egypt')
select 'UPDATE' as actiontype, getdate() as AuditDate, name, country
into #tAudit from tblCustomer where 1=2
insert into #tAudit
SELECT Actiontype, AuditDate, name, country FROM
(
MERGE tblCustomer AS target
USING (SELECT * FROM tblUpdates ) AS source
ON (target.cid = source.cid)
WHEN MATCHED
THEN UPDATE SET name = source.name, country = source.country
WHEN NOT matched
THEN INSERT
VALUES (CID,Name, Country)
OUTPUT $action as Actiontype, getdate() as AuditDate,
CASE WHEN $action = 'INSERT' THEN inserted.name ELSE deleted.name END as name,
CASE WHEN $action = 'INSERT' THEN inserted.country ELSE deleted.country END as country,
binary_checksum(inserted.name, inserted.country) as chkNew,
binary_checksum(deleted.name, deleted.country) as ChkOld) as tChanges
WHERE chkNew <> ChkOld
select * from #tAudit
drop table #tAudit
drop table tblCustomer
drop table tblUpdates
Is there a better way to achive this.
October 2, 2012 at 4:54 am
You can use the OUTPUT to insert rows into a table rather than the Outer Select, which is rather cumbersome.
this might be better, and you'd need to double check the code works but theres no reason it shouldnt
MERGE tblCustomer AS target
USING (SELECT * FROM tblUpdates ) AS source
ON (target.cid = source.cid)
WHEN MATCHED
AND (target.name!=source.name
or target.country!=source.country)
THEN UPDATE SET name = source.name, country = source.country
WHEN NOT matched
THEN INSERT
VALUES (CID,Name, Country)
OUTPUT $action
, getdate()
, CASE WHEN $action = 'INSERT' THEN inserted.name ELSE deleted.name END as name
, CASE WHEN $action = 'INSERT' THEN inserted.country ELSE deleted.country END as country
, binary_checksum(inserted.name, inserted.country) as chkNew
,binary_checksum(deleted.name, deleted.country) as ChkOld) as tChanges
INTO #tAudit
WHERE chkNew <> ChkOld
Edit I've just seen that you dont have a clause to update only the rows that have changed, so I've added it to the code this will then only update changed rows and insert new rows.
_________________________________________________________________________
SSC Guide to Posting and Best Practices
October 2, 2012 at 5:12 am
If you are using the Enterprise edition of SS2K8, then change data capture is well worth a look.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
October 2, 2012 at 6:47 am
Thank you. Your example is easier to read.
BTW I was restricting to only chnage rows by comparing the checksum values.
I didn't know you could add additional filters after is matched i.e. target.name != source.name
October 2, 2012 at 6:55 am
terry999 (10/2/2012)
Thank you. Your example is easier to read.BTW I was restricting to only chnage rows by comparing the checksum values.
I didn't know you could add additional filters after is matched i.e. target.name != source.name
Sorry theres a coding error I believe it should read
MERGE tblCustomer AS target
USING (SELECT * FROM tblUpdates ) AS source
ON (target.cid = source.cid)
WHEN MATCHED
AND (target.name!=source.name
or target.country!=source.country)
THEN UPDATE SET name = source.name, country = source.country
WHEN NOT matched
THEN INSERT
VALUES (CID,Name, Country)
OUTPUT $action
, getdate()
, CASE WHEN $action = 'INSERT' THEN inserted.name ELSE deleted.name END
, CASE WHEN $action = 'INSERT' THEN inserted.country ELSE deleted.country END
, binary_checksum(inserted.name, inserted.country)
,binary_checksum(deleted.name, deleted.country)
INTO #tAudit
_________________________________________________________________________
SSC Guide to Posting and Best Practices
October 2, 2012 at 12:23 pm
Thanks Jason
I had made that change.
From now on I will use MERGE to replace Triggers for audit - all in one place.
October 2, 2012 at 12:23 pm
illegal?
October 3, 2012 at 8:07 am
terry999 (10/2/2012)
Thanks JasonI had made that change.
From now on I will use MERGE to replace Triggers for audit - all in one place.
Note that this places the onus on the developer to code the audit stuff for EVERY SINGLE DML OPERATION ON EACH TABLE. A trigger can be written once and will capture ALL DML operations, regardless of provenance. Even if your devs are rigorous, what about that quick "oopsie" data cleanup operation you need to do because someone screwed something up. Will you ALWAYS remember to do the MERGE, even for ad hoc DML?
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
October 9, 2012 at 1:55 am
Good point, I'd forgotten that
October 9, 2012 at 3:29 am
terry999 (10/2/2012)
illegal?
Hmm, yeah. Was wondering that myself!
October 9, 2012 at 3:54 am
Gazareth (10/9/2012)
terry999 (10/2/2012)
illegal?Hmm, yeah. Was wondering that myself!
I think that Joe was probably refering to some form of regulatory requirement, eg Sarbanes Oxley/solvency II or other federal requirement to maintain data change history.
Who knows.....
_________________________________________________________________________
SSC Guide to Posting and Best Practices
October 9, 2012 at 4:11 am
Jason-299789 (10/9/2012)
Gazareth (10/9/2012)
terry999 (10/2/2012)
illegal?Hmm, yeah. Was wondering that myself!
I think that Joe was probably refering to some form of regulatory requirement, eg Sarbanes Oxley/solvency II or other federal requirement to maintain data change history.
Who knows.....
Ah yes. Luckily we're not all subject to American law... π
October 9, 2012 at 4:16 am
Gazareth (10/9/2012)
Jason-299789 (10/9/2012)
Gazareth (10/9/2012)
terry999 (10/2/2012)
illegal?Hmm, yeah. Was wondering that myself!
I think that Joe was probably refering to some form of regulatory requirement, eg Sarbanes Oxley/solvency II or other federal requirement to maintain data change history.
Who knows.....
Ah yes. Luckily we're not all subject to American law... π
If you work in the finance industry in Europe we do have Solvency II regulations that have to be in place for 2013/14 (I believe) and one of those requirements is full audit trails of data changes, including data traceability through ETL into Data Warehouse's, especially if they are used as a source for regulatory reporting to bodies like the FSA, Lloyds etc.
_________________________________________________________________________
SSC Guide to Posting and Best Practices
October 9, 2012 at 4:30 am
Jason-299789 (10/9/2012)
Gazareth (10/9/2012)
Jason-299789 (10/9/2012)
Gazareth (10/9/2012)
terry999 (10/2/2012)
illegal?Hmm, yeah. Was wondering that myself!
I think that Joe was probably refering to some form of regulatory requirement, eg Sarbanes Oxley/solvency II or other federal requirement to maintain data change history.
Who knows.....
Ah yes. Luckily we're not all subject to American law... π
If you work in the finance industry in Europe we do have Solvency II regulations that have to be in place for 2013/14 (I believe) and one of those requirements is full audit trails of data changes, including data traceability through ETL into Data Warehouse's, especially if they are used as a source for regulatory reporting to bodies like the FSA, Lloyds etc.
Fair enough π
Viewing 14 posts - 1 through 13 (of 13 total)
You must be logged in to reply to this topic. Login to reply