• Lowell (8/30/2012)


    Eric i see just a couple of things i'd change.

    the IF UPDATE(Canc) is misleading...it doesn't test if the column changed...it tests if the column was referenced in the update;

    some apps will send an update that references all columns, so you want to test for actual values.

    second thing, the way you have it, if there were multiple rows in the update, and only one of the rows had cancelled in the group, all the rows being updated would get the cancelled date, even though the canc value was still zero/null on the other rows.

    I would change it to this:

    CREATE TRIGGER dbo.tri_Cancelled

    ON Orders

    FOR UPDATE

    AS

    --objective: set the cancel date to GETDATE if the CANC value <>0

    BEGIN

    UPDATE Orders

    SET CancDate = GETDATE()

    FROM INSERTED

    WHERE Orders.OrderID = INSERTED.OrderID

    AND INSERTED.Canc <> 0

    --only change if Canc is changing in this transaction:

    --we don't want to change the date if the value of Calc is the same, but other columns are vbeing changed.

    AND Orders. Canc <> INSERTED.Canc

    END

    I think you actually have to test against the deleted table to see if anything changed. If the Canc column is nullable, you also have to take that into account.

    create trigger dbo.tri_Cancelled

    on

    Orders

    after

    update

    as

    begin

    updateOrders

    set

    CancDate = getdate()

    from

    Orders

    inner join

    deleted

    on Orders.OrderID = deleted.OrderID

    where

    Orders.Canc <> 0and

    ( deleted.Canc = 0 or deleted.Canc is null )

    end

    Also, this seems like something that would be better to do in the application when you cancel the order, instead of doing it in a trigger. Another reason to do this in the application is so you can better deal with the possibility of "un-cancelling" orders.