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

its ages since i wrote a trigger Expand / Collapse
Author
Message
Posted Thursday, August 30, 2012 3:15 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Wednesday, October 1, 2014 6:44 AM
Points: 286, Visits: 573
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?
Post #1352064
Posted Thursday, August 30, 2012 6:18 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 6:44 AM
Points: 12,905, Visits: 32,158
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1352139
Posted Thursday, August 30, 2012 6:22 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Wednesday, October 1, 2014 6:44 AM
Points: 286, Visits: 573
brilliant mate thanks for taking the time
Post #1352143
Posted Thursday, August 30, 2012 6:25 AM


SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Thursday, October 2, 2014 12:30 PM
Points: 620, Visits: 867
Might also consider changing it from an AFTER to an INSTEAD OF trigger.

_____________________________________________________________________
- Nate

@nate_hughes
Post #1352145
Posted Friday, August 31, 2012 7:21 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 11:21 AM
Points: 1,945, Visits: 3,062
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


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1352792
Posted Friday, August 31, 2012 7:36 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Wednesday, October 1, 2014 6:44 AM
Points: 286, Visits: 573
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 :)
Post #1352806
Posted Friday, August 31, 2012 8:16 AM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Friday, October 3, 2014 2:23 AM
Points: 3,108, Visits: 11,503
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

update Orders
set
CancDate = getdate()
from
Orders
inner join
deleted
on Orders.OrderID = deleted.OrderID
where
Orders.Canc <> 0 and
( 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.




Post #1352839
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse