Technical Article

Find the position of all occurrences of an expression within a string

,

/*

This inline table valued function does the same thing as CHARINDEX except that it returns a virtual table with both the relative position and the actual position of ALL occurrences of the search expression. CHARINDEX on steroids. Most useful with providing starting and ending positions for the SUBSTRING function. As an inline TVF the function can be joined to any table column with a CROSS APPLY.

*/

/* Some demonstration examples /*
DECLARE @sampledata VARCHAR(255)
SET @sampledata = '123 Main St, Albany, NY 01234'
SELECT * FROM dbo.itvfFindPos(@sampledata,',')
SET @sampledata = 'xyz,12345,SomeStuff:xyz,MoreStuff,xyz'
SELECT * FROM dbo.itvfFindPos(@sampledata,',')
;WITH sampledata
AS
(
    SELECT * FROM 
    (VALUES 
    ('xyz,12345,SomeStuff:xyz,MoreStuff,xyz'),
    ('fubar,12345,SomeStuff:fubar,MoreStuff,fubar'), 
    ('abc,12345,SomeStuff:abc,MoreStuff,abc'),
    ('boq,12345,SomeStuff:boq,MoreStuff,boq'), 
    ('fizzbin,12345,SomeStuff:fizzbin,MoreStuff,fizzbin')
) AS data([foo])
)
SELECT
    SUBSTRING(foo,fp.pos+1,9) AS foo
FROM
    sampledata s
CROSS APPLY
    dbo.itvfFindPos(s.foo,',') AS fp
WHERE
posnum = 3
;WITH sampledata
AS
(
    SELECT * FROM 
    (VALUES 
    ('111xyz,12345,SomeStuff:xyz,MoreStuff,xyz'),
    ('222fubar,12345,SomeStuff:fubar,MoreStuff,fubar'), 
    ('333abc,12345,SomeStuff:abc,MoreStuff,abc'),
    ('444boq,12345,SomeStuff:boq,MoreStuff,boq'), 
    ('555fizzbin,12345,SomeStuff:fizzbin,MoreStuff,fizzbin')
) AS data([foo])
)
SELECT
    SUBSTRING(foo,fp.pos+1,9) AS foo
FROM
    sampledata s
CROSS APPLY
    dbo.itvfFindPos(s.foo,',') AS fp
WHERE
posnum = 4
;WITH sampledata
AS
(
    SELECT * FROM 
    (VALUES 
    ('123 Main St, Albany, NY 01234'),
    ('456 Elm Ave, Los Angeles, CA 91345'),
    ('789 Oakpark Drive, Chicago, IL 45678')
) AS data([foo])
)
SELECT
    SUBSTRING(foo,fp.pos+2,8) AS foo
FROM
    sampledata s
CROSS APPLY
    dbo.itvfFindPos(s.foo,',') AS fp
WHERE
posnum = 2
;WITH sampledata
AS
(
    SELECT * FROM 
    (VALUES 
    ('xyz,12345,SomeStuff:xyz,MoreStuff,xyz'),
    ('fubar,12345,SomeStuff:fubar,MoreStuff,fubar'), 
    ('abc,12345,SomeStuff:abc,MoreStuff,abc'),
    ('boq,12345,SomeStuff:boq,MoreStuff,boq'), 
    ('fizzbin,12345,SomeStuff:fizzbin,MoreStuff,fizzbin')
) AS data([foo])
)
SELECT
     pos
    ,SUBSTRING(foo,fp.pos,3) AS foo
FROM
    sampledata s
CROSS APPLY
    dbo.itvfFindPos(s.foo,'xyz') AS fp
;WITH sampledata
AS
(
    SELECT * FROM 
    (VALUES 
    ('123 Main St, Albany, NY 01234'),
    ('456 Elm Ave, Los Angeles, CA 91345'),
    ('789 Oakpark Drive, Chicago, IL 45678')
) AS data([foo])
)
SELECT
    SUBSTRING(foo,fp.pos+2,fp1.pos-fp.pos-2) AS foo
FROM
    sampledata s
CROSS APPLY
    dbo.itvfFindPos(s.foo,',') AS fp
CROSS APPLY
    dbo.itvfFindPos(s.foo,',') AS fp1
WHERE
fp.posnum = 1
AND fp1.posnum = 2
   
CREATE FUNCTION dbo.itvfFindPos
(    
    @strInput VARCHAR(8000)
   ,@delimiter VARCHAR(50)
)
RETURNS TABLE 
AS
RETURN 
(
    WITH findchar (posnum,pos)
    AS
    (
        SELECT 
             1 AS posnum
            ,CHARINDEX(@delimiter,@strInput) AS pos
        UNION ALL
        SELECT 
             f.posnum + 1 AS posnum
            ,CHARINDEX(@delimiter,@strInput,f.pos + 1) AS pos
        FROM
            findchar f
        WHERE
            f.posnum + 1 <= LEN(@strInput)
            AND pos <> 0
    )
    SELECT
        posnum
       ,pos
    FROM
        findchar
    WHERE
        pos > 0
)
GO

Rate

4 (8)

You rated this post out of 5. Change rating

Share

Share

Rate

4 (8)

You rated this post out of 5. Change rating