February 7, 2008 at 5:07 am
while running the query in sp's I got the error message of
Msg 137, Level 15, State 1, Line 1
Must declare the scalar variable "@Rank".
SP is
SET @sql = 'SELECT top 1 @Rank = K.RANK FROM REG_TEMP1 AS C INNER JOIN '
SET @sql=@SQL + ' CONTAINSTABLE(REG_TEMP1,ST_Address_Name, ''ISABOUT("'
SET @sql=@SQL +@db
SET @sql=@SQL + '", '+@CC
SET @sql=@SQL + ' WEIGHT(0.5),'
SET @sql=@SQL +@db
SET @sql=@SQL + ' WEIGHT(0.9))'',1) AS K on C.ID = K. '
if i run the query without sp and the parameter is fixed it return values like
SELECT top 1 K.RANK, C.ST_Address_Name,C.st_address_Line_1,C.st_address_line_2,
C.ST_address_city,C.St_address_state,C.ST_address_zipcode,C.ST_address_country
FROM REG_TEMP1 AS C INNER JOIN CONTAINSTABLE(REG_TEMP1,ST_Address_Name, 'ISABOUT("CHESAPEAKE", HOSPITAL WEIGHT(0.5),CHESAPEAKE WEIGHT(0.9))',1) AS K on C.ID = K.
Can you help me, how to resolve these query using sp's
thanks & regards
Saravanakumar.R
February 7, 2008 at 5:24 am
Variable declared outside dynamic SQL aren't accessible within it, and vis versa
Your first line of dynamic SQL reads 'SELECT top 1 @Rank = K.RANK...'
Within the dynamic SQL, the variable @Rank has not been declared.
If you're trying to get values out of dynamic sQL, then look up sp_executesql in books online and note the sections on declaring and passing parameters.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
February 7, 2008 at 5:37 am
i declared initially
Declare @Rank as varchar(2000)
set @Rank=null
then
Sp'Query
but passing the values is from table.
thanks & regards
February 7, 2008 at 5:49 am
It's declared outside of the dynamic SQL string. If you want the variable accessible inside the dynamic SQL, you either have to declare it within the dynamic SQL string, or use sp_executesql and declare it as a parameter
This will throw an error - variable not declared
DECLARE @sql varchar(max), @SomeVar int
SET @SomeVar = 0
SET @sql = 'SELECT @SomeVar'
EXEC (@sql) -- error @somevar not declared
This will work fine.
DECLARE @sql varchar(max)
SET @sql = 'DECLARE @SomeVar int'
SET @sql = @sql + ' SET @SomeVar = 0 '
SET @sql = @sql + ' SELECT @SomeVar'
EXEC (@sql)
This will also work fine
DECLARE @sql nvarchar(max), @SomeVar int
SET @SomeVar = 0
SET @sql = 'SELECT @SomeOtherVar'
exec sp_executesql @sql, N'@SomeOtherVar int', @SomeOtherVar = @SomeVar
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
February 7, 2008 at 9:34 am
Gail - a general question and a hair split. First the hair split - do you need a trailing space on the first line of your "SET @sql = 'text'" so it reads ...'text '?
General question - do you need to delimit your SQL statements in some way so SQL Server knows where one statement ends and another begins, or is that handled automatically by using separate SET statements? I haven't had the chance to use this in so long, I've forgotten (and being too lazy to look it up).
Steve
February 7, 2008 at 10:31 pm
thnaks for your reply. i will check with my store procedure and reply you back Gail.
thanks & regards
Saravanakumar.R
February 7, 2008 at 11:31 pm
1) No, however if you're concatenating pieces of string together, you'll need a space somewhere.
2) No. SQL doesn't care about whitespace. Lay things out that they are readable by you and anyone reading the code in the future.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply