Many a time we come across a scenario where we pass a comma or any other character delimited string to stored procedure and in stored procedure we want to fetch data from other tables based this delimited string. We can’t use this delimited string directly in the in clause as Sql treats it as one string. So, the solution for this is to get a table by splitting the delimited string by the delimiter character and then join this resultant table data with other table columns.
In Sql Server we have mechanism where we can take table as a input parameter from the application code. So if you like to pass a table from your code with multiple rows instead of passing a delimited string to stored procedure and splitting it in SP, then you may like to read the article Table-Valued Parameters in Sql Server. But I would prefer passing the comma delimited string to stored procedure and split it in the SP.
In Sql Server we have multiple approaches to achieve this. This article lists couple of them. Please let me know which one you use and if you use some-other approach let me know, so that we can help the Sql Server developer community
APPROACH 1: Sql Server 2016 STRING_SPLIT function
STRING_SPLIT is one of the new built-in table valued function introduced in Sql Server 2016. This table valued function splits the input string by the specified character separator and returns output as a table.
Below example shows how we can use STRING_SPLIT function to splits the comma separated string.
SELECT * FROM STRING_SPLIT('Basavaraj,Kalpana,Shree',',')
To know in detail about the STRING_SPLIT function you may like to read the article: STRING_SPLIT function in Sql Server 2016
APPROACH 2: Using While Loop and Sql String Functions
We can crate a table valued function like the below which is using WHILE loop and Sql String functions like CHARINDEX and SUBSTRING to split the string. This should work in all the versions of Sql Server.
CREATE FUNCTION [dbo].StringSplit ( @String VARCHAR(MAX), @Separator CHAR(1) ) RETURNS @RESULT TABLE(Value VARCHAR(MAX)) AS BEGIN DECLARE @SeparatorPosition INT = CHARINDEX(@Separator, @String ), @Value VARCHAR(MAX), @StartPosition INT = 1 IF @SeparatorPosition = 0 BEGIN INSERT INTO @RESULT VALUES(@String) RETURN END SET @String = @String + @Separator WHILE @SeparatorPosition > 0 BEGIN SET @Value = SUBSTRING(@String , @StartPosition, @SeparatorPosition- @StartPosition) IF( @Value <> '' ) INSERT INTO @RESULT VALUES(@Value) SET @StartPosition = @SeparatorPosition + 1 SET @SeparatorPosition = CHARINDEX(@Separator, @String , @StartPosition) END RETURN END
Below example shows how we can use the above function to split the comma delimited string
SELECT * FROM StringSplit('Basavaraj,Kalpana,Shree',',')
APPROACH 3: Using XML
We can crate a table valued function like the below which is using Sql XML feature to split the string.
CREATE FUNCTION [dbo].StringSplitXML ( @String VARCHAR(MAX), @Separator CHAR(1) ) RETURNS @RESULT TABLE(Value VARCHAR(MAX)) AS BEGIN DECLARE @XML XML SET @XML = CAST( ('<i>' + REPLACE(@String, @Separator, '</i><i>') + '</i>') AS XML) INSERT INTO @RESULT SELECT t.i.value('.', 'VARCHAR(MAX)') FROM @XML.nodes('i') AS t(i) WHERE t.i.value('.', 'VARCHAR(MAX)') <> '' RETURN END
Below example shows how we can use the above function to split the comma delimited string
SELECT * FROM StringSplitXML('Basavaraj,Kalpana,Shree',',')