Update a date field with a Trigger when a transaction is posted to another table

  • 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

    ) ;

  • 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.

  • 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.

  • 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.

  • 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.

  • 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.

    šŸ˜Ž

  • 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.

  • 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?

  • 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.

    šŸ˜Ž

  • 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.

  • Eirikur Eiriksson (5/11/2014)


    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.

    šŸ˜Ž

    True and the only reason to restrict the update would be to reduce logging or prevent the regression of the date (ie update only if the date is greater than the current value)

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

  • I'm using SQL Server 2008 R2.

  • jeremy 64107 (5/11/2014)


    I'm using SQL Server 2008 R2.

    Too bad my ESP (Extrasensory perception) connection is down:-P The create table statements for both tables and the update statement sql code is needed at this point.

    Check out this article on how to post a problem[/url]

    šŸ˜Ž

  • Sorry - I'm confused now and not following. Thanks anyway.

  • jeremy 64107 (5/11/2014)


    Sorry - I'm confused now and not following. Thanks anyway.

    To try to figure out what the error you are getting we need the SQL used to create the tables so that we can see the column names and data types plus the SQL you used to insert/update the data.

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

Viewing 15 posts - 1 through 15 (of 27 total)

You must be logged in to reply to this topic. Login to reply