Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

passing CSV "array" to a stored proc Expand / Collapse
Author
Message
Posted Sunday, November 4, 2012 4:35 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, January 22, 2013 3:58 PM
Points: 3, Visits: 11
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
Post #1380844
Posted Sunday, November 4, 2012 4:43 PM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:07 PM
Points: 941, Visits: 1,766
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

Post #1380846
Posted Sunday, November 4, 2012 4:46 PM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:07 PM
Points: 941, Visits: 1,766
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
Post #1380848
Posted Sunday, November 4, 2012 5:09 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, October 31, 2014 6:31 AM
Points: 107, Visits: 514
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.
Post #1380851
Posted Sunday, November 4, 2012 5:54 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 11:50 PM
Points: 3,440, Visits: 5,397
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!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1380857
Posted Monday, November 5, 2012 8:30 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Friday, December 19, 2014 2:05 PM
Points: 13,327, Visits: 12,820
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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1381120
Posted Monday, November 5, 2012 5:10 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, January 22, 2013 3:58 PM
Points: 3, Visits: 11
Thanks a lot all!
Post #1381321
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse