June 25, 2004 at 12:27 pm
Here's my problem...this will not work:
declare @retval int, @tablename char(12), @procedure varchar(1000)
set @tablename = 'ExampleTable'
set @procedure = 'select count(*) from ' + @tablename
set @retval = exec(@procedure)
Any ideas? I need to plug a row count into a variable in a dynamic query, where the tablename is different every time.
June 25, 2004 at 12:44 pm
Try this:
DECLARE @tablename char(12), @procedure varchar(1000)
set @tablename = 'Groupings'
set @procedure = 'declare @retval int; select @retval = count(*) from ' + @tablename + '; select @retVal'
exec(@procedure)
The Exec command does not have any return values. Also all the statements inside the Exec command are one batch and the lifetime of the variables declared within the exec statement is only for the duration of the execution of the Exec statement. So, if I gave a "Select @Retval" after the exec call, it would not recognize the @RetVal variable.
June 25, 2004 at 1:00 pm
yeah, that works, but i need to return the value or set it to a variable
June 25, 2004 at 1:43 pm
i got what i needed...cept i had to select a value from a temp table into a cursor that did a "fetch next into" my variable.
June 28, 2004 at 4:57 am
Use sp_executesql
This gets me the count of records in tbl_clients. I just posted this to microsoft.public.sqlserver.programming as well.
declare @mySQL nvarchar(4000)
declare @CountRec int
SET @mySQL = 'SELECT @CountParm = COUNT(*) FROM tbl_clients'
exec sp_executesql @mySQL, N'@CountParm INT OUTPUT', @CountParm = @CountRec OUTPUT
select @CountRec
June 28, 2004 at 6:47 am
here's one function I like to use (works only with that have a Primary key):
CREATE FUNCTION [dbo].[CountALL] (@sTableName as varchar(255))
RETURNS int AS
BEGIN
--this is about 6 times faster than count(*) according to the execution plan
--and it sure beats the hell out of full table scan to count all the rows on a big table
return isnull((Select max(rowcnt) as Total from dbo.sysindexes where id = object_id(@sTableName) and indid < 2), 0)
END
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply