August 30, 2012 at 3:15 am
Ive written this one
create trigger dbo.tri_Cancelled
on Orders
for update
as
if Update(Canc)
begin
if (Select Canc from Inserted) <> 0
Begin
UPdate Orders set CancDate = getDate() where OrderID = (Select OrderID from Inserted)
end
end
reckon it could be written better?
August 30, 2012 at 6:18 am
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
Lowell
August 30, 2012 at 6:22 am
brilliant mate thanks for taking the time
August 30, 2012 at 6:25 am
Might also consider changing it from an AFTER to an INSTEAD OF trigger.
_____________________________________________________________________
- Nate
August 31, 2012 at 7:36 am
CELKO (8/31/2012)
The real goal is to get rid of the trigger completely and replce it with declaraitve code. We do have DDL or specs, so we cannot help you get into a set-oriented, declarative style of thinking.I am trying to figure what "canc" is as a data element. The naem is a violationof ISO-11179 and makes no sesne when you read it. It looks like a flag, but that is absurd. If I update the cancellation_date from NULL to CURRENT_TIMESTAMP, I would not need a flag
these field names or tables names are not the real ones used
i wouldnt want anyone i work with noticing i am consulting a forum like this 🙂
August 31, 2012 at 8:16 am
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.
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply