Update Triggers not working for dependent columns

  • I have encountered a strange situation where the update trigger on a table is not updating columns that are dependent on other columns which are also getting updated during the update. Here is the background and the code for replicating this problem.

    I have a commodities management application that keeps track of fruit prices everyday. I have a need to calculate the Price and Volume trend for fruits on a daily purpose. The daily Fruit prices and price volume calculations are stored in the FruitTrades table. I have defined an Update trigger on this table which will calculate the Price and Volume trend whenever a row is inserted or updated in this table.

    The daily fruit prices and volume come to me in a flat file which I import into a simple Table called PriceData. Then I move the Price and Volume information from this table to the FruitTrades table using a simple INSERT statement. This fires the update triggers in the FruitTrades, but two of the columns do not get updated by the trigger. Any idea why?

    Steps for replicating this problem are as follows:

    -- STEP 1 (create the FruitTrades table)

    CREATE TABLE [dbo].[FruitTrades](

    [FID] [nchar](3) NOT NULL,

    [TradeDate] [smalldatetime] NOT NULL,

    [TAID] [tinyint] NULL,

    [Price] [real] NOT NULL,

    [Vol] [int] NULL,

    [3DAvgPrice] [real] NULL,

    [5DAvgPrice] [real] NULL,

    [VolTrend] [real] NULL,

    [VolTrendPrevD] [real] NULL,

    CONSTRAINT [PK_FruitTrades] PRIMARY KEY CLUSTERED

    (

    [FID] ASC,

    [TradeDate] DESC

    )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]

    ) ON [PRIMARY];

    -- STEP 2 (Create the Update trigger)

    CREATE TRIGGER [dbo].[TRG_FruitTrades_Analysis]

    ON [dbo].[FruitTrades]

    AFTER INSERT, UPDATE

    AS

    BEGIN

    -- SET NOCOUNT ON added to prevent extra result sets from

    -- interfering with SELECT statements.

    SET NOCOUNT ON;

    UPDATE FruitTrades SET

    -- Calculate the 3 day average price

    [FruitTrades].[3DAvgPrice] =

    (

    SELECT AVG(Price) FROM

    (

    SELECT TOP 3 Price FROM FruitTrades

    WHERE FID = [Inserted].[FID] AND TradeDate <= [Inserted].[TradeDate]

    ) AS Last3Trades

    ),

    -- Calculate the 5 day average price

    [FruitTrades].[5DAvgPrice] =

    (

    SELECT AVG(Price) FROM

    (

    SELECT TOP 5 Price FROM FruitTrades

    WHERE FID = [Inserted].[FID] AND TradeDate <= [Inserted].[TradeDate]

    ) AS Last5Trades

    ),

    -- Fetch the previous days VolTrend and update VolTrendPrev column

    [FruitTrades].[VolTrendPrevD] =

    (

    SELECT TOP 1 VolTrend FROM FruitTrades

    WHERE FID = [Inserted].[FID] AND TradeDate < [Inserted].[TradeDate]

    ),

    -- Calculate Volume Trend and update VolTrend column

    [FruitTrades].[VolTrend] =

    (

    ISNULL([FruitTrades].[VolTrendPrevD], 0) +

    ([Inserted].[Vol] * (([Inserted].[Price] /

    (SELECT TOP 1 Price FROM FruitTrades WHERE FID = [Inserted].[FID] AND TradeDate < [Inserted].[TradeDate])) - 1.0 ))

    ),

    -- Now Update the Action ID column

    [FruitTrades].[TAID] =

    (

    CASE

    WHEN [FruitTrades].[3DAvgPrice] >= [FruitTrades].[5DAvgPrice] AND [FruitTrades].[VolTrend] >= [FruitTrades].[VolTrendPrevD] THEN 1

    WHEN [FruitTrades].[3DAvgPrice] >= [FruitTrades].[5DAvgPrice] AND [FruitTrades].[VolTrend] <= [FruitTrades].[VolTrendPrevD] THEN 2

    WHEN [FruitTrades].[3DAvgPrice] <= [FruitTrades].[5DAvgPrice] AND [FruitTrades].[VolTrend] >= [FruitTrades].[VolTrendPrevD] THEN 3

    WHEN [FruitTrades].[3DAvgPrice] <= [FruitTrades].[5DAvgPrice] AND [FruitTrades].[VolTrend] <= [FruitTrades].[VolTrendPrevD] THEN 4

    ELSE NULL

    END

    )

    FROM FruitTrades

    INNER JOIN Inserted ON Inserted.FID = FruitTrades.FID AND Inserted.TradeDate = FruitTrades.TradeDate

    END

    -- STEP 3 (Create the PriceData table)

    CREATE TABLE [dbo].[PriceData](

    [FID] [nchar](3) NOT NULL,

    [TradeDate] [smalldatetime] NOT NULL,

    [Price] [real] NULL,

    [Vol] [real] NULL,

    CONSTRAINT [PK_PriceData] PRIMARY KEY CLUSTERED

    (

    [FID] ASC,

    [TradeDate] ASC

    )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]

    ) ON [PRIMARY]

    -- STEP 4 (simulate data import into PriceData table)

    INSERT INTO PriceData (FID, TradeDate, Price, Vol) VALUES ('APL', '4/30/2012', 200, 1000);

    INSERT INTO PriceData (FID, TradeDate, Price, Vol) VALUES ('APL', '4/29/2012', 190, 1200);

    INSERT INTO PriceData (FID, TradeDate, Price, Vol) VALUES ('APL', '4/28/2012', 195, 1250);

    INSERT INTO PriceData (FID, TradeDate, Price, Vol) VALUES ('APL', '4/27/2012', 205, 1950);

    INSERT INTO PriceData (FID, TradeDate, Price, Vol) VALUES ('APL', '4/26/2012', 200, 2000);

    INSERT INTO PriceData (FID, TradeDate, Price, Vol) VALUES ('APL', '4/25/2012', 180, 1300);

    INSERT INTO PriceData (FID, TradeDate, Price, Vol) VALUES ('APL', '4/24/2012', 185, 1250);

    -- STEP 5 (move price vol date from PriceDate table to Fruit Tables)

    INSERT INTO FruitTrades (FID, TradeDate, Price, Vol) SELECT FID, TradeDate, Price, Vol FROM PriceData;

    -- STEP 6 (check the FruitTrades table for correctness)

    SELECT * FROM FruitTrades ORDER BY TradeDate

    --- Results

    After Step 6 you will find that the TAID and VolTrendPrevD in the FruitTrades table columns remain NULL.

    Any help on how to resolve this problem is appreciated.

  • After laboring on this problem for 5 days, and some Googling, I finally found the solution myself.

    The first problem was on account of my lack of understanding of triggers and how they fire. As per SQL documentation,

    "SQL Server triggers fire only once per statement, not once per affected row".

    Due to this design principle, when in Step 5, I do a bulk Insert from the PriceData table into the FruitTrades table, the trigger is fired only once, instead of once for each row. Hence the Updated values are incorrect.

    The VolTrendPrevD remains null because the Select statement for it in the Update trigger always matches the first row in the FruitTrades table (since the Inserted table has multiple rows) and for this row, the VolTrend is null.

    The TAID remains null because VolTrendPrevD is null.

    Now the fix:

    1. Import the text file containing the price data into a MSaccess table. From there do a bulk insert in to the SQL Server table (using Linked tables). This approach uses ODBC to convert the bulk insert into multiple single inserts, thus bypassing the first problem.

    2. Convert the VolTrend into a computed column. There is no need to update it therefore in the trigger.

    3. Introduce an additional column PricePrevD in the FruitTrades table and update its value in the trigger, in the same manner as the VolTrendPrevD column.

    4. Most importantly, ensure that the inserted rows from Access are inserted in ascending order by date (by creating an appropriate date index in Access). Else the desired results will be missing.

    Hope this helps... 🙂

  • The problem is in the logic of your trigger. You need to write code that can handle sets of data instead of single rows at a time.

    When you do things like this...

    [FruitTrades].[VolTrendPrevD] =

    (

    SELECT TOP 1 VolTrend FROM FruitTrades

    WHERE FID = [Inserted].[FID] AND TradeDate < [Inserted].[TradeDate]

    ),

    ...you are not properly handling more than 1 row in your trigger. Also, you have here a top 1 but there is no order by. This means your top 1 is whatever row sql wants to give you.

    You could make this trigger work but it would take a complete rewrite to do it correctly.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

Viewing 3 posts - 1 through 2 (of 2 total)

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