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


Trigger error


Trigger error

Author
Message
lleemon13
lleemon13
Valued Member
Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)

Group: General Forum Members
Points: 59 Visits: 99
I have a table called SRVC00200 which I created a trigger. What I am trying to do is when the field SRVSTAT is updated I want to get a value from the row that was updated and pass that value to another stored procedure.

Right now I am testing by doing the following:
update SVC00200 set SRVSTAT = 800 where CALLNBR = '0000016736'

I get the following error:
Msg 208, Level 16, State 1, Procedure tr_CHECK_SRVSTAT, Line 11
Invalid object name 'TRAIN.dbo.inserted'.

Any ideas why this doesn't work?


USE [TRAIN]
GO
/****** Object: Trigger [dbo].[tr_CHECK_SRVSTAT] Script Date: 07/21/2009 09:47:25 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

ALTER TRIGGER [dbo].[tr_CHECK_SRVSTAT]
ON [TRAIN].[dbo].[SVC00200]
AFTER UPDATE
AS
DECLARE @CALLNBR varchar(50)
DECLARE @SRVSTAT char(3)

IF UPDATE(SRVSTAT)
BEGIN
SELECT @SRVSTAT = SRVSTAT,
@CALLNBR = CALLNBR
FROM [TRAIN].[dbo].inserted

IF @SRVSTAT = 800
BEGIN
--CALL SP THAT PASSES CALLNBR AND IF HAS NOT BEEN EMAILED THEN SEND EMAIL AND UPDATE
EXEC sp_webServiceRequest_EmailComplete @CALLNBR
END

END


Lowell
Lowell
SSCoach
SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)

Group: General Forum Members
Points: 19128 Visits: 39461
a simple syntax error;
INSERTED is a virtual table that exists just inside the trigger...so there is no table called [TRAIN].[dbo].inserted [/b]

this should be:

SELECT @SRVSTAT = SRVSTAT,
@CALLNBR = CALLNBR
FROM inserted




note your trigger has a logic error in it; it would not work correctly if two or more rows were updated at the same time.

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!

lleemon13
lleemon13
Valued Member
Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)

Group: General Forum Members
Points: 59 Visits: 99
Yes, that worked. Any documentation on handling multiples?
anitha.sudhir
anitha.sudhir
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 5
Trigger will be called as many rows gets updated , so that should work ,

USE [TRAIN]
GO
/****** Object: Trigger [dbo].[tr_CHECK_SRVSTAT] Script Date: 07/21/2009 09:47:25 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
ALTER TRIGGER [dbo].[tr_CHECK_SRVSTAT]
ON [TRAIN].[dbo].[SVC00200]
AFTER UPDATE
AS
DECLARE @CALLNBR varchar(50)
DECLARE @SRVSTAT char(3)
IF UPDATE(SRVSTAT)
BEGIN
SELECT @SRVSTAT = SRVSTAT,
@CALLNBR = CALLNBR
FROM INSERTED
IF @SRVSTAT = 800
BEGIN
--CALL SP THAT PASSES CALLNBR AND IF HAS NOT BEEN EMAILED THEN SEND EMAIL AND UPDATE
EXEC sp_webServiceRequest_EmailComplete @CALLNBR
END
END
Lynn Pettis
Lynn Pettis
One Orange Chip
One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)

Group: General Forum Members
Points: 27742 Visits: 38157
Triggers in SQL Server are fired once regardless of the number of rows inserted/updated/deleted. If the possibility exists, you need to code your triggers to handle multiple rows.

I'd start by reading BOL (Books Online). If that creates more questions than answers, come back and ask specific questions for clarification.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Lowell
Lowell
SSCoach
SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)

Group: General Forum Members
Points: 19128 Visits: 39461
anitha is incorrect, he's confusing the way oracle or other databases handle triggers, vs the way SQL Server works.

SQL Server's trigger is called once for any statement, whether it is one row or a million rows.

in your case, since you need to call a stored proc to send your email, you'd want to do call the procedure one time for each row inserted.

this trigger I'm pasting below would correctly execute for each item that met the criteria; note the one thing missing is the Primary key of the inserted and deleted tables..i assumed "ID" was the column name, but you'd need to change that.


--USE [TRAIN]
GO
/****** Object: Trigger [dbo].[tr_CHECK_SRVSTAT] Script Date: 07/21/2009 09:47:25 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO

ALTER TRIGGER [dbo].[tr_CHECK_SRVSTAT]
ON [TRAIN].[dbo].[SVC00200]
AFTER UPDATE
AS
BEGIN --Trigger body
DECLARE @CALLNBR VARCHAR(64)

DECLARE C1 CURSOR FOR
SELECT
INSERTED.CALLNBR
FROM INSERTED
INNER JOIN DELETED
ON INSERTED.ID = DELETED.ID
WHERE INSERTED.SRVSTAT <> DELETED.SRVSTAT --had to change from previous value
AND INSERTED.SRVSTAT= 800 --changed to 800
OPEN C1
FETCH NEXT FROM C1 INTO @CALLNBR
WHILE @@fetch_status <> -1
BEGIN
EXEC sp_webServiceRequest_EmailComplete @CALLNBR
FETCH NEXT FROM C1 INTO @CALLNBR
END
CLOSE C1
DEALLOCATE C1
END--Trigger body





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!

Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (55K reputation)SSC Guru (55K reputation)SSC Guru (55K reputation)SSC Guru (55K reputation)SSC Guru (55K reputation)SSC Guru (55K reputation)SSC Guru (55K reputation)SSC Guru (55K reputation)

Group: General Forum Members
Points: 55508 Visits: 40405
I'd sure NOT put anything in a trigger that has to do with actual emailing or any other form of RBAR unless you like getting phone calls about why the server is so slow. The most I'd do is have it fill another table with the information in a set based fashion and let a separate email "crawler" proc handle sending the emails.

If you don't think so, consider what happens if the email server goes down. ;-)

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
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