September 22, 2016 at 3:24 am
Hi,
I am trying to create store procedure, which has requirement to pass multiple Strings as input for Store Proc, Could someone help me how to do this.
Example:
Create Store Procedure FindingCityNames @CountryNames varchar(200)
as
select CityName,Capital, Countryname
from TableCountries
where
CountryName in
(
@CountryNames)
-- If I pass One country Name, I am able to see the Output, but If I want to pass like 'UK', 'USA', 'NZ', then its not accepting and returning error as "Procedure or function dd has too many arguments specified."
Please help me how to handle this.
Many Thanks
September 22, 2016 at 3:30 am
What you need here is a table valued parameter:
CREATE TYPE ParamCountry AS TABLE (name varchar(200));
GO
CREATE PROCEDURE FindingCityNames @CountryNames ParamCountry READONLY
AS
SELECT CityName,Capital, Countryname
FROM TableCountries
WHERE CountryName IN (
SELECT name
FROM @CountryNames
)
GO
DECLARE @names AS ParamCountry;
INSERT INTO @names VALUES ('UK'), ('USA'), ('NZ');
EXEC FindingCityNames @names;
GO
-- Gianluca Sartori
September 22, 2016 at 6:24 am
It's easy enough to break up an input string with a string splitter...
DECLARE @States VARCHAR(255) = 'NY,NJ,FL,OK,OH,MD';
SELECT
s.StateAbbr
FROM
dbo.LK_States s
JOIN dbo.DelimitedSplit8k(@States, ',') ds
ON s.StateAbbr = ds.Item;
September 22, 2016 at 7:12 am
You've got two great options here. If by any way you get an option of using dynamic sql, please avoid it unless you plan to go unemployed.
The splitter that Jason used can be found here along with its explanation: http://www.sqlservercentral.com/articles/Tally+Table/72993/
September 23, 2016 at 10:24 am
Just for what it's worth, we used to use the string splitter approach until the developers finally bit the bullet and learned to use table valued parameters. They are really a lot more efficient, especially when you're splitting input values just to populate a work table.
__________________________________________________
Against stupidity the gods themselves contend in vain. -- Friedrich Schiller
Stop, children, what's that sound? Everybody look what's going down. -- Stephen Stills
September 23, 2016 at 12:50 pm
The Dixie Flatline (9/23/2016)
Just for what it's worth, we used to use the string splitter approach until the developers finally bit the bullet and learned to use table valued parameters. They are really a lot more efficient, especially when you're splitting input values just to populate a work table.
Agreed.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply