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


INSTEAD OF trigger and OUTPUT clause


INSTEAD OF trigger and OUTPUT clause

Author
Message
tlewis-993411
tlewis-993411
SSC Rookie
SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)

Group: General Forum Members
Points: 37 Visits: 80
I selected "Returns an error". It didn't seem right, but I'm not sure why the following code works

INSERT TestTable (string)
OUTPUT inserted.*

Doesn't the select return more columns (ID and String) than the insert list? That is one of my more common errors...

Great question, BTW. I need to learn more about OUTPUT!
vk-kirov
vk-kirov
Hall of Fame
Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)Hall of Fame (3.5K reputation)

Group: General Forum Members
Points: 3494 Visits: 4408
tlewis-993411 (5/13/2010)
I'm not sure why the following code works

INSERT TestTable (string)
OUTPUT inserted.*

Doesn't the select return more columns (ID and String) than the insert list?

When a row is inserted into a table, SQL Server fills all columns in that row. All these columns are contaned in the 'inserted.*' construct. Some of these values are explicit, and some are implicit (NULL, identity, default value, computed value etc).

Here is an example:
create table #t
( id int identity,
a varchar(10),
b varchar(10) default 'hello',
c varchar(10),
computed_column as b + ' ' + c
)

insert #t (c)
output inserted.*
values ('test')



In the QOTD, the construct 'OUTPUT inserted.*' is equal to 'OUTPUT inserted.id, inserted.string'. 'Inserted.string' is an explicit column, while 'inserted.id' is an impilcit column.
tlewis-993411
tlewis-993411
SSC Rookie
SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)

Group: General Forum Members
Points: 37 Visits: 80
My problem is that I expected that "inserted" would be a complete copy of the inserted row (I haven't used OUTPUT, but triggers certainly work that way). As such, the Inserted.* should return 2 columns, but the insert list only contains one field. See the code below and the resulting error message. This is almost exactly the same construct.

I'll do some research, but it appears that Output is only returning the "explicitly added" columns?

BTW, generically, I'm opposed to * for this very reason!

Declare @foo Table
(
ID int,
String varchar(100)
)

Insert into @Foo(String)
Select * from
(Select 1 as intval, 'sample1' as string
union all
Select 2 as intval, 'sample2' as string
) as bar

Msg 121, Level 15, State 1, Line 7
The select list for the INSERT statement contains more items than the insert list. The number of SELECT values must match the number of INSERT columns.
Jedak
Jedak
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2519 Visits: 1109
Toreador (5/13/2010)
Interesting - it never occurred to me that the identity values wouldn't be available in the inserted table!
So how would you get the identity values of the rows you'd just inserted?


If you are using an instead of trigger, I'm not sure. However, not using an instead of trigger works fine to retrieve the identity values using OUTPUT. I ran the below on SQL Server 2008.

CREATE TABLE Test
(
ID int identity(1,1) NOT NULL PRIMARY KEY,
AnotherColumn varchar(50) NULL
)
GO

CREATE TRIGGER Test_Insert
ON Test
AFTER INSERT
AS
SELECT 'Trigger Executed'
GO

DECLARE @tTableVar table(TestID int NOT NULL,
TestAnotherColumn varchar(50) NULL)


INSERT INTO Test(AnotherColumn)
OUTPUT inserted.ID, inserted.AnotherColumn
INTO @tTableVar(TestID,TestAnotherColumn)
SELECT 'Blah'
UNION ALL
SELECT 'Blah2'

SELECT TestID,TestAnotherColumn FROM @tTableVar

DROP TABLE Test


tlewis-993411
tlewis-993411
SSC Rookie
SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)

Group: General Forum Members
Points: 37 Visits: 80
Duh - The "Into @Tab" is not using the Select, but instead the output, which does include two columns.

Select * into a table (or Output * into table, in this case) only works if the fields are selected in the same order and same count as the target, which is obviously true in this case. However, I would still avoid the * if possible, explicitly naming the fields instead. Otherwise, a change to the target table would break that condition.

Thanks for putting up with me working through my own question. That's how I learn almost everything!
Chad Crawford
 Chad Crawford
SSCrazy
SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)

Group: General Forum Members
Points: 2438 Visits: 18651
HA HA HA! I took a guess (which was wrong), but checked by running the code before I answered (some consider this cheating, I consider it "using all available resources for the task at hand"). But I forgot to change my answer before submitting, so I still got it wrong! Serves me right, I guess! :-P

Chad
ronmoses
ronmoses
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1093 Visits: 996
Wow, this was such a good question, I wish I'd written it! :-D I learned at least three things from it, so I don't mind having gotten it wrong.

-----
a haiku...

NULL is not zero
NULL is not an empty string
NULL is the unknown

Bradley Deem
Bradley Deem
Mr or Mrs. 500
Mr or Mrs. 500 (567 reputation)Mr or Mrs. 500 (567 reputation)Mr or Mrs. 500 (567 reputation)Mr or Mrs. 500 (567 reputation)Mr or Mrs. 500 (567 reputation)Mr or Mrs. 500 (567 reputation)Mr or Mrs. 500 (567 reputation)Mr or Mrs. 500 (567 reputation)

Group: General Forum Members
Points: 567 Visits: 1248
Toreador (5/13/2010)
Interesting - it never occurred to me that the identity values wouldn't be available in the inserted table!
So how would you get the identity values of the rows you'd just inserted?


Change the trigger as follows. Of course, I'm not sure how you would capture the output result set, save using the temp table method as previously mentioned, but then the caller would have to know to look for that temp table.
CREATE TRIGGER TestTrigger ON TestTable
INSTEAD OF INSERT
AS
INSERT TestTable (string)
OUTPUT INSERTED.*
SELECT CASE WHEN string = 'TestString' THEN string ELSE 'Stub' END
FROM inserted



Excellent question, I definitely learned something today!
UMG Developer
UMG Developer
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2280 Visits: 2204
Great question and learned a couple things in the process, a very good start to a day.

Thanks!
SQLRNNR
SQLRNNR
SSC-Insane
SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)

Group: General Forum Members
Points: 21075 Visits: 18259
Thanks for a great question.



Jason AKA CirqueDeSQLeil
I have given a name to my pain...
MCM SQL Server, MVP


SQL RNNR

Posting Performance Based Questions - Gail Shaw

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