-- Create central accounts static table
CREATE TABLE CentralOfficeAccounts (
account_nbr INT PRIMARY KEY,
company_name VARCHAR(35),
primary_contact VARCHAR(35),
contact_phone VARCHAR(12));
-- Daily updated branch data
CREATE TABLE BranchOfficeAccounts (
account_nbr INT PRIMARY KEY,
company_name VARCHAR(35),
primary_contact VARCHAR(35),
contact_phone VARCHAR(12));
-- Insert sample data
INSERT INTO CentralOfficeAccounts
VALUES (1, 'Bayside Motors', 'Jim Smith', '902-203-1234'),
(2, 'Dallas Industries', 'Joe Doe', '301-663-9134'),
(3, 'Sky Computer Systems', 'Jane Brown', '201-943-6053');
INSERT INTO BranchOfficeAccounts
VALUES (2, 'Dallas Industries, Inc.', 'Rick Gross', '301-663-9134'), -- changed
(3, 'Sky Computer Systems', 'Jane Brown', '201-943-6053'), -- same
(4, 'Auto Insurance Co.', 'Chris Jefferson', '313-601-6201'); -- new
-- Table for auditing
CREATE TABLE AccountsAudit (
account_nbr INT,
change_action NVARCHAR(10),
change_date DATETIME DEFAULT CURRENT_TIMESTAMP,
old_company_name VARCHAR(35),
new_company_name VARCHAR(35),
PRIMARY KEY(account_nbr, change_action, change_date));
-- Single SQL statement performing the merge and auditing actions
INSERT INTO AccountsAudit
(account_nbr, change_action, old_company_name, new_company_name)
SELECT account_nbr, merge_action, old_company_name, new_company_name
FROM (MERGE INTO CentralOfficeAccounts AS C
USING BranchOfficeAccounts AS B
ON C.account_nbr = B.account_nbr
WHEN MATCHED
AND C.company_name <> B.company_name THEN
UPDATE SET C.company_name = B.company_name
WHEN NOT MATCHED THEN
INSERT (account_nbr, company_name,
primary_contact, contact_phone)
VALUES (B.account_nbr, B.company_name,
B.primary_contact, B.contact_phone)
WHEN SOURCE NOT MATCHED THEN
DELETE
OUTPUT $action,
COALESCE(inserted.account_nbr, deleted.account_nbr),
deleted.company_name,
inserted.company_name
) AS T(merge_action, account_nbr, old_company_name, new_company_name);
SELECT account_nbr, change_action, change_date,
old_company_name, new_company_name
FROM AccountsAudit;
/*
-- Results
account_nbr change_action change_date old_company_name new_company_name
----------- ------------- ----------- ------------------ -----------------------
1 DELETE 2008-04-15 Bayside Motors NULL
2 UPDATE 2008-04-15 Dallas Industries Dallas Industries, Inc.
4 INSERT 2008-04-15 NULL Auto Insurance Co.
*/
Labels: sql server 2008, t-sql programming