Results 1 to 6 of 6

Thread: Update Trigger

  1. #1
    Join Date
    May 2006
    Posts
    2

    Unanswered: Update Trigger

    Hallo there,

    I'm totally new to writing triggers, but managed to get a trigger to update a specific column (ufINCTcost) on change of another column (ufINCKm)

    My problem is that the trigger performs this update on ALL rows, which makes it very slow. How can I get it to only update the column on the row where the change was made ?

    My trigger looks as follows:


    CREATE TRIGGER updateincidents ON [dbo].[_rtblIncidents]
    FOR UPDATE, INSERT
    AS
    IF UPDATE (ufINCKm)
    BEGIN
    UPDATE dbo._rtblIncidents
    SET ufINCTcost=dbo._rtblIncidents.ufINCKm+dbo._rtblInc idents.ufINCToll+dbo._rtblIncidents.ufINCParking+d bo._rtblIncidents.ufINCFlight+dbo._rtblIncidents.u fINCRental

    Hope you can help !!

  2. #2
    Join Date
    Nov 2004
    Location
    on the wrong server
    Posts
    8,835
    Provided Answers: 6
    look into joining to the inserted virtual table. also your trigger assumes only one record will be inserted or updated at a time. this is bad.
    “If one brings so much courage to this world the world has to kill them or break them, so of course it kills them. The world breaks every one and afterward many are strong at the broken places. But those that will not break it kills. It kills the very good and the very gentle and the very brave impartially. If you are none of these you can be sure it will kill you too but there will be no special hurry.” Earnest Hemingway, A Farewell To Arms.

  3. #3
    Join Date
    Jul 2003
    Location
    The Dark Planet
    Posts
    1,401
    This should do the work ... just replace primarykey with your primary key column name
    Code:
    CREATE TRIGGER updateincidents ON [dbo].[_rtblIncidents] 
    FOR UPDATE, INSERT
    AS
    IF UPDATE (ufINCKm)
    BEGIN
    UPDATE a
    SET a.ufINCTcost=a.ufINCKm+a.ufINCToll+a.ufINCParking+a.ufINCFlight+a.ufINCRental
    FROM dbo._rtblIncidents a
    ,inserted b
    where a.primarykey = b.primarykey
    Get yourself a copy of the The Holy Book

    order has no physical Brett in The meaning of a Kaiser . -database data

  4. #4
    Join Date
    Jun 2004
    Posts
    50
    You can use the @@ROWCOUNT system function if you're concerned about dealing with multiple rows.

    IF @@ROWCOUNT=1
    some logic
    ELSE
    some logic
    Monk
    The person who confesses ignorance shows it once; the person who conceals it shows it many times.

  5. #5
    Join Date
    Jun 2003
    Location
    Ohio
    Posts
    12,592
    Provided Answers: 1
    I gotta butt in here Enigma, because you should be encouranging him to use JOIN syntax:
    Code:
    CREATE	TRIGGER updateincidents ON [dbo].[_rtblIncidents] 
    FOR UPDATE, INSERT
    AS
    IF UPDATE (ufINCKm)
    BEGIN
    UPDATE	a
    SET	a.ufINCTcost=a.ufINCKm+a.ufINCToll+a.ufINCParking+a.ufINCFlight+a.ufINCRental
    FROM	dbo._rtblIncidents a
    	INNER JOIN inserted b ON a.primarykey = b.primarykey
    Also Nel, be aware that the IF UPDATE statement can be a little misleading. It returns true anytime that column is part of the affected dataset, even if the value does not actually change. For instance:
    Code:
    update	dbo._rtblIncidents
    set	ufINCKm = ufINCKm
    will cause IF UPDATE to return true.

    If you really want to be sure the value was modified, you need to check the DELETED table.

    ...and I don't think @@RowCount is applicable in this situation.

    ...and why are you starting object names with an underscore? That's ugly.

    OK. That's all my gripes tonight.
    If it's not practically useful, then it's practically useless.

    blindman
    www.chess.com: "sqlblindman"
    www.LobsterShot.blogspot.com

  6. #6
    Join Date
    May 2006
    Posts
    2
    Thanks for all your help !

    Bringing in the virtual table, and linking the primary keys did the trick !

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •