Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 123»»»

Update a date field with a Trigger when a transaction is posted to another table Expand / Collapse
Author
Message
Posted Saturday, May 10, 2014 8:55 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, May 12, 2014 1:25 AM
Points: 14, Visits: 13
Hello,

I’m wondering if you can please help me.
I have two tables. Customers.UniqueID and Transheaders.AccountID
In Customers I have a field called ZLastSale.
I want to create a Trigger to update the ZLastSale field when a transaction is posted to the Transheaders table which inserts to the TradingDate field so I can capture the last sale date on a Customer.

This is my current example however it is not updating the ZLastdate field.

CREATE TRIGGER trg_LastSaleDate ON dbo.Transheaders
AFTER UPDATE
AS
IF UPDATE(TradingDate)
BEGIN
UPDATE c
SET ZLastSales = i.TradingDate
FROM dbo.Customers AS c
JOIN inserted AS i
ON i.UniqueID = c.UniqueID
JOIN deleted AS d
ON i.AccountID = d.AccountID
AND ( i.TradingDate <> d.TradingDate
OR d.TradingDate IS NULL
) ;
Post #1569571
Posted Saturday, May 10, 2014 11:11 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 1:25 PM
Points: 2,420, Visits: 6,735
You might be slightly over complicating a simple thing, look through this example


USE tempdb;
GO
/*
Sample Schema, Client and Transactions
*/
/* Drop the tables if they exist in the database */
IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = N'TBL_HEADER'
AND TABLE_SCHEMA = N'dbo')
DROP TABLE dbo.TBL_HEADER;

IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = N'TBL_CLIENT'
AND TABLE_SCHEMA = N'dbo')
DROP TABLE dbo.TBL_CLIENT;

/* Create simplified transaction table */
CREATE TABLE dbo.TBL_HEADER
(
HEADER_ID INT IDENTITY(1,1) PRIMARY KEY CLUSTERED NOT NULL
,CLIENT_ID INT NOT NULL
,HEADER_DATE DATETIME2(0) NOT NULL DEFAULT(SYSDATETIME())
,HEADER_TRANSACTIONDATE DATETIME2(0) NOT NULL
);

/* Create simplified client table */
CREATE TABLE dbo.TBL_CLIENT
(
CLIENT_ID INT IDENTITY(1,1) PRIMARY KEY CLUSTERED NOT NULL
,CLIENT_NAME NVARCHAR(128) NOT NULL
,CLIENT_TRANSACTIONDATE DATETIME2(0) NOT NULL
);
GO

/*
Now for the fun stuff, this is a trigger that updates the
client table every time a new transaction is inserted or
updated in the transaction table. It ignores deletes as
the DELETE keyword is missing in the scope definition which
is the line directly after the target object name
(ON dbo.TBL_HEADER)

The trigger uses the two pseudo tables, [inserted] and [deleted].

For inserts, the inserted values are found in the [inserted]
table but the [deleted] is empty.

For updates, the [inserted] holds the new values and the
[deleted] has the old values. If the value is unchanged,
the trigger ignores the record.
*/

CREATE TRIGGER dbo.TRG_HEADER_UPDATE_CLIENT_TRANSACTIONDATE
/* Schema qualified target object name */
ON dbo.TBL_HEADER
/* DML scope, which data manipulation events will fire the
trigger
*/
AFTER INSERT, UPDATE
AS
/*
Trigger code
*/
UPDATE CL
SET CL.CLIENT_TRANSACTIONDATE = INS.HEADER_TRANSACTIONDATE
FROM inserted INS
INNER JOIN dbo.TBL_CLIENT CL
ON INS.CLIENT_ID = CL.CLIENT_ID
LEFT OUTER JOIN deleted DE
ON CL.CLIENT_ID = DE.CLIENT_ID
/* For inserts there are no records in the [deleted] pseudo table. Therefore it
is referenced by a left outer join, which returns NULL for inserts. The
ISNULL then substitudes the NULL with the current value in the client table to
determine whether to update the record or not.
*/
WHERE INS.HEADER_TRANSACTIONDATE <> ISNULL(DE.HEADER_TRANSACTIONDATE,CL.CLIENT_TRANSACTIONDATE)
;
GO

/* Sample data for clients */
INSERT INTO dbo.TBL_CLIENT (CLIENT_NAME,CLIENT_TRANSACTIONDATE)
VALUES
(N'Alpha' ,'2000-01-01')
,(N'Beta' ,'2000-02-01')
,(N'Gamma' ,'2000-03-01')
,(N'Delta' ,'2000-04-01')
,(N'Epsilon','2000-05-01')
,(N'Zeta' ,'2000-06-01');

/* verify the clients */
SELECT * FROM dbo.TBL_CLIENT;

/* insert a single transactional record */
INSERT INTO dbo.TBL_HEADER (CLIENT_ID,HEADER_TRANSACTIONDATE)
SELECT
CL.CLIENT_ID
,'2001-01-01'
FROM dbo.TBL_CLIENT CL
WHERE CL.CLIENT_NAME = N'Alpha';

/* Results */
SELECT * FROM dbo.TBL_CLIENT;

/* insert multiple transactional records */
INSERT INTO dbo.TBL_HEADER (CLIENT_ID,HEADER_TRANSACTIONDATE)
SELECT
CL.CLIENT_ID
,'2002-01-02'
FROM dbo.TBL_CLIENT CL
WHERE CL.CLIENT_NAME <> N'Alpha';

/* Results */
SELECT * FROM dbo.TBL_CLIENT;
SELECT * FROM dbo.TBL_HEADER;

/* update single transactional record */
UPDATE H
SET H.HEADER_TRANSACTIONDATE = '2003-01-02'
FROM dbo.TBL_CLIENT CL
INNER JOIN dbo.TBL_HEADER H
ON CL.CLIENT_ID = H.CLIENT_ID
WHERE CL.CLIENT_NAME = N'Alpha';

/* Results */
SELECT * FROM dbo.TBL_CLIENT;
SELECT * FROM dbo.TBL_HEADER;

/* update multiple transactional records */
UPDATE H
SET H.HEADER_TRANSACTIONDATE = '2004-03-02'
FROM dbo.TBL_CLIENT CL
INNER JOIN dbo.TBL_HEADER H
ON CL.CLIENT_ID = H.CLIENT_ID
WHERE CL.CLIENT_NAME <> N'Alpha';

/* Results */
SELECT * FROM dbo.TBL_CLIENT;
SELECT * FROM dbo.TBL_HEADER;

Update: Added comments.
Post #1569575
Posted Sunday, May 11, 2014 12:57 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, May 12, 2014 1:25 AM
Points: 14, Visits: 13
Wow, that looks complicated!
I didn't write my script I had it provided to me.
I am new to Triggers, so that script really means nothing to me.
Are you able to assist me further? Thank you so much.
Post #1569576
Posted Sunday, May 11, 2014 1:27 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:02 AM
Points: 7,013, Visits: 7,180
The trigger looks OK apart from

ZLastSale, ZLastdate and ZLastSales (which is the correct name)
It only processes updates to Transheaders
What about inserts to Transheaders?



Far away is close at hand in the images of elsewhere.

Anon.

Post #1569577
Posted Sunday, May 11, 2014 1:33 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, May 12, 2014 1:25 AM
Points: 14, Visits: 13
The correct name is ZLastDate.

If a new transaction for a particular Customer is entered then the Transheaders table should fire the Trigger and update only that Customers record. (As in if a new invoice is posted this will update the transheaders table)

Thanks.
Post #1569578
Posted Sunday, May 11, 2014 2:06 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 1:25 PM
Points: 2,420, Visits: 6,735
jeremy 64107 (5/11/2014)
Wow, that looks complicated!
I didn't write my script I had it provided to me.
I am new to Triggers, so that script really means nothing to me.
Are you able to assist me further? Thank you so much.


It looks more complex than it really is
I added some detailed comments in the code, let us know if you need further assistance.
Post #1569579
Posted Sunday, May 11, 2014 2:17 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:02 AM
Points: 7,013, Visits: 7,180
In that case use Eirikur's trigger although you could simplify it to
CREATE TRIGGER trg_LastSaleDate ON dbo.Transheaders
AFTER INSERT, UPDATE
AS
IF UPDATE(TradingDate)
BEGIN
UPDATE c
SET c.ZLastDate = i.TradingDate
FROM inserted i
JOIN dbo.Customers c ON c.UniqueID = i.UniqueID
END




Far away is close at hand in the images of elsewhere.

Anon.

Post #1569580
Posted Sunday, May 11, 2014 2:40 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, May 12, 2014 1:25 AM
Points: 14, Visits: 13
Thank You.
I ran the script and it worked fine.
When I test the transaction in my system I am getting this error:

Microsoft ODBC SQL Driver SQL Server Conversion failed when converting the varchar value '' to data type int.

Is the data field incorrect?
Post #1569582
Posted Sunday, May 11, 2014 2:44 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 1:25 PM
Points: 2,420, Visits: 6,735
David Burrows (5/11/2014)
In that case use Eirikur's trigger although you could simplify it to
CREATE TRIGGER trg_LastSaleDate ON dbo.Transheaders
AFTER INSERT, UPDATE
AS
IF UPDATE(TradingDate)
BEGIN
UPDATE c
SET c.ZLastDate = i.TradingDate
FROM inserted i
JOIN dbo.Customers c ON c.UniqueID = i.UniqueID
END



Slight difference in the logic, this code will do an update every time, even if the existing value is equal to the update value.
Post #1569584
Posted Sunday, May 11, 2014 2:45 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 6:02 AM
Points: 7,013, Visits: 7,180
Please post DDL for the two tables and the SQL you used to test with.


Far away is close at hand in the images of elsewhere.

Anon.

Post #1569585
« Prev Topic | Next Topic »

Add to briefcase 123»»»

Permissions Expand / Collapse