passing CSV "array" to a stored proc

  • Hi, am trying to pass 'Orange,Guava' argurment to this stored Proc. dbo.TESCOS table has two columns, Fruit varchar(100) and Price int. I keep getting errors >> Msg 207, Level 16, State 1, Line 3

    Invalid column name 'Guava'.

    Any help? thanks!

    USE [Paul]

    GO

    /****** Object: StoredProcedure [dbo].[FruitPrice] Script Date: 11/04/2012 23:07:56 ******/

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    -- Batch submitted through debugger: SQLQuery12.sql|7|0|C:\Users\Paul\AppData\Local\Temp\~vsD79B.sql

    ALTER PROC [dbo].[FruitPrice]

    (

    @OrderList varchar(500)

    )

    AS

    BEGIN

    SET NOCOUNT ON

    DECLARE @SQL varchar(400)

    SET @SQL =

    'SELECT Fruit,Price

    FROM dbo.TESCOS

    WHERE Fruit IN (' + @OrderList + ')'

    EXEC(@SQL)

    END

  • You need to surround the fruits with '

    i.e. '''Orange'',''Guava'''

    DECLARE @SQL AS VARCHAR(MAX)

    DECLARE @OrderList AS VARCHAR(MAX) = '''Orange'',''Guava'''

    SET @SQL =

    'SELECT Fruit,Price

    FROM dbo.TESCOS

    WHERE Fruit IN (' + @OrderList + ')'

    SELECT @SQL

  • by the way, depending on what you are trying to do there are other ways of passing lists of parameters into a stored procedure. for example xml or table-valued parameters.

    regards

    David

  • There are no quotes around the names of your fruits so they are being interpreted as column names.

    if the string you passed in was like this,

    set @sql = ''''+'guava'+''''+','+''''+'orange'+''''

    it would work fine. That being said, you probably want to search for "string splitter" on here and use one of the prerolled methods for using comma delimited strings.

  • qrius (11/4/2012)


    Hi, am trying to pass 'Orange,Guava' argurment to this stored Proc. dbo.TESCOS table has two columns, Fruit varchar(100) and Price int. I keep getting errors >> Msg 207, Level 16, State 1, Line 3

    Invalid column name 'Guava'.

    Any help? thanks!

    USE [Paul]

    GO

    /****** Object: StoredProcedure [dbo].[FruitPrice] Script Date: 11/04/2012 23:07:56 ******/

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    -- Batch submitted through debugger: SQLQuery12.sql|7|0|C:\Users\Paul\AppData\Local\Temp\~vsD79B.sql

    ALTER PROC [dbo].[FruitPrice]

    (

    @OrderList varchar(500)

    )

    AS

    BEGIN

    SET NOCOUNT ON

    DECLARE @SQL varchar(400)

    SET @SQL =

    'SELECT Fruit,Price

    FROM dbo.TESCOS

    WHERE Fruit IN (' + @OrderList + ')'

    EXEC(@SQL)

    END

    You don't need dynamic SQL at all for this:

    ALTER PROC [dbo].[FruitPrice]

    (

    @OrderList varchar(500)

    )

    AS

    BEGIN

    SET NOCOUNT ON

    SELECT Fruit,Price

    FROM dbo.TESCOS

    WHERE Fruit IN (SELECT Item FROM DelimitedSplit8K(@OrderList, ','))

    END

    Where the DelimitedSplit8K FUNCTION can be found here: http://www.sqlservercentral.com/articles/Tally+Table/72993/


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Not only is Dwain 1000000% correct about not using dynamic sql for this, your dynamic sql is wide open to sql injection. You are directly executing a string passed in.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Thanks a lot all!

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

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