Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


its ages since i wrote a trigger


its ages since i wrote a trigger

Author
Message
erics44
erics44
Old Hand
Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)

Group: General Forum Members
Points: 366 Visits: 739
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?
Lowell
Lowell
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14973 Visits: 38989
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

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

erics44
erics44
Old Hand
Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)

Group: General Forum Members
Points: 366 Visits: 739
brilliant mate thanks for taking the time
RP_DBA
RP_DBA
Right there with Babe
Right there with Babe (767 reputation)Right there with Babe (767 reputation)Right there with Babe (767 reputation)Right there with Babe (767 reputation)Right there with Babe (767 reputation)Right there with Babe (767 reputation)Right there with Babe (767 reputation)Right there with Babe (767 reputation)

Group: General Forum Members
Points: 767 Visits: 1069
Might also consider changing it from an AFTER to an INSTEAD OF trigger.

_____________________________________________________________________
- Nate

@nate_hughes
erics44
erics44
Old Hand
Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)Old Hand (366 reputation)

Group: General Forum Members
Points: 366 Visits: 739
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 Smile
Michael Valentine Jones
Michael Valentine Jones
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3260 Visits: 11771
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.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search