April 13, 2010 at 9:22 pm
Comments posted to this topic are about the item Rowcount and multiple assignment
April 13, 2010 at 9:50 pm
This is a great question, I really, really enjoyed it. The most difficult part was to figure out that the line:
set @result = cast (@@rowcount as varchar)
does 2 things:
1. it sets the value of the @result variable to 1 because @@rowcount was equal to 1 as a result of the last insert
2. it resets @@rowcount to 1 as a result of @result assignment.
The @@rowcount then stays unchanged (still equal to 1) because the
select @result = @result + cast (@@rowcount as varchar) from #n;
which pads the @result has the @@rowcount inside of it, but the moment the statement bails out the @@rowcount is then reset to whatever the number of affected records was, which happens to be 3.
The commented line reading set nocount off; was there just for demonstration purposes I suppose, meaning that it could be any other set statement, such as set ansi_nulls on; or set transaction isolation level read uncommitted; or whatever other set. Any such set statement when uncommented would just reset the @@rowcount to 0 changing the final answer to 10003 from 11113.
I really hope that what I figured is correct, and my answer was not a result of some lucky guess.
Thanks again.
Oleg
April 14, 2010 at 12:15 am
Oleg Netchaev (4/13/2010)
This is a great question, I really, really enjoyed it. The most difficult part was to figure out that the line:
set @result = cast (@@rowcount as varchar)
does 2 things:
1. it sets the value of the @result variable to 1 because @@rowcount was equal to 1 as a result of the last insert
2. it resets @@rowcount to 1 as a result of @result assignment.
The @@rowcount then stays unchanged (still equal to 1) because the
select @result = @result + cast (@@rowcount as varchar) from #n;
which pads the @result has the @@rowcount inside of it, but the moment the statement bails out the @@rowcount is then reset to whatever the number of affected records was, which happens to be 3.
The commented line reading set nocount off; was there just for demonstration purposes I suppose, meaning that it could be any other set statement, such as set ansi_nulls on; or set transaction isolation level read uncommitted; or whatever other set. Any such set statement when uncommented would just reset the @@rowcount to 0 changing the final answer to 10003 from 11113.
I really hope that what I figured is correct, and my answer was not a result of some lucky guess.
Thanks again.
Oleg
Thank you.
My interest writing the script was the behaviour of @@rowcount during mulitple assignment in single select.
Yes, you are right, the commented set statement is there just to be uncommented to show the change of the result.
You figured it very well.
April 14, 2010 at 2:01 am
This was removed by the editor as SPAM
April 14, 2010 at 3:23 am
It's important to note that SET @result = cast (@@rowcount as varchar) does NOT change @@ROWCOUNT. The first 1 comes from the last INSERT #n VALUES(3).
This is one of the important differences between SELECT and SET when assigning variables. SET never yields a rowcount, and thus doesn't change @@ROWCOUNT.
April 14, 2010 at 6:14 am
I'm not ashamed to admit that I've read this problem and the solution several times, as well as the corresponding BOL topics, and I still can't make heads or tails of it. This question has easily made me feel more thick-headed than any other I've seen here, so well done, Honza! Ultimately I had to pick an answer at random just so I could get to the forum thread, where hopefully my head will be pulled from my a** with a resounding POP! 😀
-----
a haiku...
NULL is not zero
NULL is not an empty string
NULL is the unknown
April 14, 2010 at 6:42 am
Sorry, ronmoses, for your headache.
I was curious about one thing, and I decided to make it a QotD, I mixed several things together.
To tell the truth, greatest work was to write all the answers 🙂
April 14, 2010 at 6:52 am
honza.mf (4/14/2010)
Sorry, ronmoses, for your headache.
Oh, no need for an apology, my post was intended as a compliment! Most of the questions I see here are either things I can easily get my head around (whether I know the answer or not) or things that are way outside the realm of my current experience level. This question should have been the former, and I'm kinda happy to be struggling with it. So thanks for the great question!
-----
a haiku...
NULL is not zero
NULL is not an empty string
NULL is the unknown
April 14, 2010 at 7:50 am
That was fun and surprising. I didn't notice the quirky update until I ran it.
Thanks for a good QotD.
Rune Bivrin (4/14/2010)
It's important to note that SET @result = cast (@@rowcount as varchar) does NOT change @@ROWCOUNT. The first 1 comes from the last INSERT #n VALUES(3).This is one of the important differences between SELECT and SET when assigning variables. SET never yields a rowcount, and thus doesn't change @@ROWCOUNT.
That does not seem to be true. @@ROWCOUNT yields the result of the last command. SET yields 1 whereas PRINT yields 0.
declare @n varchar(5)
select @n = @@rowcount
/*Row count is 1 after SELECT*/
print @@rowcount
/*Row count is 0 after PRINT*/
print @@rowcount
set @n = @@rowcount
/*Row count is 1 after SET*/
print @@rowcount
April 14, 2010 at 8:05 am
Tom Garth (4/14/2010)
That was fun and surprising. I didn't notice the quirky update until I ran it.Thanks for a good QotD.
Rune Bivrin (4/14/2010)
It's important to note that SET @result = cast (@@rowcount as varchar) does NOT change @@ROWCOUNT. The first 1 comes from the last INSERT #n VALUES(3).This is one of the important differences between SELECT and SET when assigning variables. SET never yields a rowcount, and thus doesn't change @@ROWCOUNT.
That does not seem to be true. @@ROWCOUNT yields the result of the last command. SET yields 1 whereas PRINT yields 0.
declare @n varchar(5)
select @n = @@rowcount
/*Row count is 1 after SELECT*/
print @@rowcount
/*Row count is 0 after PRINT*/
print @@rowcount
set @n = @@rowcount
/*Row count is 1 after SET*/
print @@rowcount
As said in BOL:
Statements that make a simple assignment always set the @@ROWCOUNT value to 1. No rows are sent to the client. Examples of these statements are: SET @local_variable, RETURN, READTEXT, and select without query statements such as SELECT GETDATE() or SELECT 'Generic Text'.
Statements that make an assignment in a query or use RETURN in a query set the @@ROWCOUNT value to the number of rows affected or read by the query, for example: SELECT @local_variable = c1 FROM t1.
Data manipulation language (DML) statements set the @@ROWCOUNT value to the number of rows affected by the query and return that value to the client. The DML statements may not send any rows to the client.
DECLARE CURSOR and FETCH set the @@ROWCOUNT value to 1.
EXECUTE statements preserve the previous @@ROWCOUNT.
Statements such as USE, SET <option>, DEALLOCATE CURSOR, CLOSE CURSOR, BEGIN TRANSACTION or COMMIT TRANSACTION reset the ROWCOUNT value to 0.
But there is something strange as "SELECT GETDATE()" returns a row to the client. Author probably omitted some "@d=". It happens.
April 14, 2010 at 8:50 am
Very cool QotD -- thanks!
April 14, 2010 at 9:00 am
Rune Bivrin (4/14/2010)
It's important to note that SET @result = cast (@@rowcount as varchar) does NOT change @@ROWCOUNT. The first 1 comes from the last INSERT #n VALUES(3).This is one of the important differences between SELECT and SET when assigning variables. SET never yields a rowcount, and thus doesn't change @@ROWCOUNT.
Are you sure about this? I tried the following on my server and did not get a result consistent with your statement above. I am using SQL 2005
declare @result int
select 1 union select 2
set @result = @@rowcount
select @@rowcount
I got
-----------
1
2
-----------
1
April 14, 2010 at 9:03 am
Rune Bivrin (4/14/2010)
It's important to note that SET @result = cast (@@rowcount as varchar) does NOT change @@ROWCOUNT. The first 1 comes from the last INSERT #n VALUES(3).This is one of the important differences between SELECT and SET when assigning variables. SET never yields a rowcount, and thus doesn't change @@ROWCOUNT.
I am sorry, but this is just plain wrong. Here is the proof showing that when I said that the line
set @result = cast (@@rowcount as varchar);
does 2 things (sets the value of @result to 1 because @@rowset was equal to 1 as a result of the last insert, and then resets the value of @@rowcount back to one).
Lets change the original script to substitute 3 inserts (each inserting one record) with a single insert inserting 3 records in one set. If your statement about SET never yields a rowcount is correct then we should see the final answer as 33333, but the result is actually going to be 31113 insead.
declare @result varchar (5);
create table #n (n int);
insert into #n
select
top 3 row_number() over (order by [object_id])
from sys.objects;
-- @@rowcount is equal to 3 after the insert, and @@rowcount is equal
--to 1 after the set below is executed, so set @result = ... does indeed
--sets the rowcount. The confusion comes from the fact that the statements
-- such as set ansi_nulls, quoted_identifier or whatever other set do not
-- have so-called rows affected so those set statements reset the @@rowcount
-- to 0, that is all. They still change the value of the @@rowcount though :)
set @result = cast (@@rowcount as varchar);
select @result = @result + cast (@@rowcount as varchar) from #n;
select @result + cast (@@rowcount as varchar);
The above yields 31113 not 33333
Oleg
April 14, 2010 at 9:07 am
This is a nice example of why you SHOULD NOT test @@ROWCOUNT at the start of a trigger and exit if the value is zero. Although this technique has been documented in independent books (e.g., Ken Henderson) the value could be zero from some other action performed by some other trigger or program unit (procedure, function). I.e., the value of @@ROWCOUNT does not always reflect the number of rows affected in the table that the trigger is attached to when the trigger is fired.
April 14, 2010 at 9:26 am
Oleg,
insert into #n
select
top 3 row_number() over (order by [object_id])
from sys.objects;
is not the same as
insert #n values (1)
insert #n values (2)
insert #n values (3)
Should you check the @@rowcount after performing your select, it will return 3, meaning that there were 3 rows affected by your SQL call.
In the individual inserts,it will return a 1 after the last insert command.
@@ROWCOUNT changes after each SQL call, which is why it needs to be immediately after any command which you want to check the rowcont of.
@@ROWCOUNT returns the specific number of rows either returned from a query or affected by a transaction. The value of @@ROWCOUNT is ALWAYS the value of the immediate preceeding SQL call. Thus, your example is selecting 3 rows and inserting them as a batch. The QOD is performing 3 seperate inserts.
Steve Jimmo
Sr DBA
“If we ever forget that we are One Nation Under God, then we will be a Nation gone under." - Ronald Reagan
Viewing 15 posts - 1 through 15 (of 27 total)
You must be logged in to reply to this topic. Login to reply