November 3, 2006 at 5:28 am
drop
table #test
declare
@rows int
create
table #test (id int identity , val varchar(100))
insert
#test
select
top 100('hello')
from
syscolumns
set
@rows = @@rowcount
insert
#test
select
top (@@rowcount)'bye'
from
syscolumns
select
* from #test
i want to get the row count from a insert statement and then use it in the top clause of another statement but the assigment to the local variable appears to set the rowcount back to one. Anyone got any ideas?
November 3, 2006 at 5:42 am
November 3, 2006 at 6:01 am
@@rowcount returns number of rows affected by LAST statement.
Any questions?
_____________
Code for TallyGenerator
November 3, 2006 at 3:26 pm
In addition to what Sergiy stated, SQL Server 2000 does not allow you to use a variable value for the number of rows returned by TOP. Look up 'SET ROWCOUNT' in BOL.
November 4, 2006 at 3:30 am
Can u explain the use of 'set rowcount' with realtime examples. I went thru the Sql help but it didn't impress me..
November 5, 2006 at 8:53 am
Ok... One picture is worth a thousand words...
--===== Conditionally drop the temp table
IF OBJECT_ID('TEMPDB..#Test') IS NOT NULL
DROP TABLE #Test
DECLARE @Rows INT
CREATE TABLE #Test (ID INT IDENTITY(1,1), Val VARCHAR(100))
INSERT #Test (Val)
SELECT TOP 100('HELLO')
FROM SYSCOLUMNS
SET @Rows = @@ROWCOUNT
--===== Limit the number of rows processed for all further queries
SET ROWCOUNT @Rows
INSERT #Test
SELECT 'BYE'
FROM SYSCOLUMNS
--===== Remove limit on number of rows processed for all further queries
SET ROWCOUNT 0
SELECT * FROM #Test
--Jeff Moden
Change is inevitable... Change for the better is not.
November 6, 2006 at 8:49 am
Thanks for the example Jeff.
Faizjmc, it is important to note that Jeff set the ROWCOUNT back to zero after he was finished. Don't forget to do this! Forgetting to do this will limit your result sets for the duration of that connection.
November 6, 2006 at 8:52 pm
Spot on, John...
--Jeff Moden
Change is inevitable... Change for the better is not.
November 6, 2006 at 9:43 pm
10q John n Jeff
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply