replace variable values in run time

  • I have sql statements saved as field value in a table. I am looping through the table and executing those sql queries . What i need to do is replace the variable value during run time.

    Lets say I have @r ='TOM', next run i have @r='Sara'

    SELECT * FROM Table1 WHERE Name=@R

    how can i achieve this?

  • Be easier to help if you provide some Ddl and how are you calling stored procedure or setting the variables. Initially i would look up dynamic sql perhaps do you have an example execution

    ***The first step is always the hardest *******

  • SGT_squeequal (11/8/2013)


    Be easier to help if you provide some Ddl and how are you calling stored procedure or setting the variables. Initially i would look up dynamic sql perhaps do you have an example execution

    DECLARE @sql NVARCHAR(200)

    DECLARE @InComeAmountB INT=500

    SET @sql='SELECT * FROM [DB1].[dbo].[DailyIncome] WHERE IncomeAmount>@IncomeAmount'

    SET @sql=REPLACE(@Sql,'@IncomeAmount','@InComeAmountB')

    Exec (@Sql)

    The sql (@Sql) is hardcoded and is stored in a table.

    This is what i am trying to do.

  • This example @sql is that the string stored in db?

    ***The first step is always the hardest *******

  • SET @sql=REPLACE(@Sql,'@IncomeAmount','@InComeAmountB')

    Try

    Set @sql=Select substring(@Sql,0,charindex('>',@sql))+cast(@InComeAmountB as varchar)

    Exec (@sql)

    ***The first step is always the hardest *******

  • peacesells (11/8/2013)


    SGT_squeequal (11/8/2013)


    Be easier to help if you provide some Ddl and how are you calling stored procedure or setting the variables. Initially i would look up dynamic sql perhaps do you have an example execution

    DECLARE @sql NVARCHAR(200)

    DECLARE @InComeAmountB INT=500

    SET @sql='SELECT * FROM [DB1].[dbo].[DailyIncome] WHERE IncomeAmount>@IncomeAmount'

    SET @sql=REPLACE(@Sql,'@IncomeAmount','@InComeAmountB')

    Exec (@Sql)

    The sql (@Sql) is hardcoded and is stored in a table.

    This is what i am trying to do.

    Don't use EXEC for this, use sp_executesql but you will need to be able to build/provide a list of parameters with it:

    declare @sql nvarchar(200), @params nvarchar(200);

    declare @incomeamountb int=500;

    set @sql=n'select * from [db1].[dbo].[dailyincome] where incomeamount > @incomeamount'

    set @params=n'@incomeamount int';

    exec sp_executesql @sql,@params,@incomeamountb

    This is also a step in the right direction for protecting against sql injection...

    MM



    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);

  • Forum Etiquette: How to post Reporting Services problems
  • [/url]
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • [/url]
  • How to Post Performance Problems - by Gail Shaw
  • [/url]

  • mister.magoo (11/8/2013)


    peacesells (11/8/2013)


    SGT_squeequal (11/8/2013)


    Be easier to help if you provide some Ddl and how are you calling stored procedure or setting the variables. Initially i would look up dynamic sql perhaps do you have an example execution

    DECLARE @sql NVARCHAR(200)

    DECLARE @InComeAmountB INT=500

    SET @sql='SELECT * FROM [DB1].[dbo].[DailyIncome] WHERE IncomeAmount>@IncomeAmount'

    SET @sql=REPLACE(@Sql,'@IncomeAmount','@InComeAmountB')

    Exec (@Sql)

    The sql (@Sql) is hardcoded and is stored in a table.

    This is what i am trying to do.

    Don't use EXEC for this, use sp_executesql but you will need to be able to build/provide a list of parameters with it:

    declare @sql nvarchar(200), @params nvarchar(200);

    declare @incomeamountb int=500;

    set @sql=n'select * from [db1].[dbo].[dailyincome] where incomeamount > @incomeamount'

    set @params=n'@incomeamount int';

    exec sp_executesql @sql,@params,@incomeamountb

    This is also a step in the right direction for protecting against sql injection...

    I haven't tried out this yet, i wonder if this will because i also i have group by clause which is hardcoded in the query stored in the query . so for instance the query i posted earlier would look smth like this.

    SET @sql='SELECT a, b, c , sum(d) FROM [DB1].[dbo].[DailyIncome] WHERE IncomeAmount>@IncomeAmount Group by a, b, c'

  • Not sure what your question is there?

    Having group by in your query won't matter one jot.

    MM



    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);

  • Forum Etiquette: How to post Reporting Services problems
  • [/url]
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • [/url]
  • How to Post Performance Problems - by Gail Shaw
  • [/url]

    Viewing 8 posts - 1 through 7 (of 7 total)

    You must be logged in to reply to this topic. Login to reply