Technical Article

Simple and efficient way to split string with seperator

,

   I have seen too many people write function to split string with loop. This maybe not efficient, especially if you want to apply the function with large tables.
   The function fn_SplitString here is very simple and it is also very efficient. It does not use any looping. So we can apply it to a large table with very good performance. 
   I had few very good experience using similar idea to parse address string with large tables in the past.
    It uses an internal table master..spt_values from SQL server, which is avaliable for all version of SQL server. This table is also available from Sybase. So this same function and same idea will work with Sybase too.
    Currently the function remove the potential empty space at end of begin of the string value, but you may choose not to do that.
     If you prefer not to use internal system table, you can use other ways to generate a table with list of numbers.
     
     The function is easy to use, for example:
     
     select stringNumber, stringValue from fn_SplitString('split;my;string;with;a;separator',';')

       This is what you get as the result:

--
-- Steven Rao
-- June 15, 2013
-- A simple and efficient way to split string with separator
-- It has very good performance since no looping is used
USE [TEST]
GO

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[fn_SplitString]') AND type in (N'FN', N'IF', N'TF', N'FS', N'FT'))
DROP FUNCTION [dbo].[fn_SplitString]
GO

SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

CREATE FUNCTION [dbo].[fn_SplitString](@string AS VARCHAR(8000), @stringSeperator AS CHAR(1))
RETURNS TABLE
AS

RETURN
SELECT
(number - 1) - LEN(REPLACE(LEFT(@string, number - 1), @stringSeperator, '')) + 1 AS stringNumber
,LTRIM(RTRIM(SUBSTRING(@string, number, CHARINDEX(@stringSeperator, @string + @stringSeperator, number) - number))) AS stringValue
FROM(select number from master..spt_values where type='p') as numbers
WHEREnumber <= LEN(@string) + 1
AND SUBSTRING(@stringSeperator + @string, number, 1) = @stringSeperator;

GO

Rate

2.5 (4)

You rated this post out of 5. Change rating

Share

Share

Rate

2.5 (4)

You rated this post out of 5. Change rating