split string to three parts

  • I have a comma delimited string that's made up of 3 parts:

    Word1, Word2, Word3

    I want to spli the string and place this into three separate variables, @Word1, @Word2 and @Word3

    but sometimes the string contains just two words, sometimes all three and sometimes just one. For example

    ',Word2,'

    ',,Word3'

    'Word1,,'

    I've tried using a function to split the string and return a table of rows but I'm not sure how to identify each row.

    Any ideas?

    ---------------------------------------------------------

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • If you are talking about splitting single string (let say passed as parameter) into three variables, you don't really need a function, as you will not get much benefits from using it.

    You can do it in number of ways, one is here:

    declare @Word1 varchar(100), @Word2 varchar(100), @Word3 varchar(100)

    declare @STR varchar(100) = 'Word1,Word2,Word3'

    --declare @STR varchar(100) = ',Word2,'

    --declare @STR varchar(100) = ',,Word3'

    --declare @STR varchar(100) = 'Word1,,'

    --declare @STR varchar(100) = ',,'

    SELECT @Word1 = LEFT(@str, CHARINDEX(',',@str)-1)

    ,@Word2 = LEFT(SUBSTRING(@str, CHARINDEX(',',@str)+1,LEN(@str)), CHARINDEX(',',SUBSTRING(@str, CHARINDEX(',',@str)+1,LEN(@str)))-1)

    ,@Word3 = REVERSE(LEFT(REVERSE(@str), CHARINDEX(',',REVERSE(@str))-1))

    select @Word1,@Word2,@Word3

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Hah... loko this is what I had come up with but I got errors when I tried various combinations:

    declare @string varchar(100) = 'surname, forename, middlename'

    declare @string varchar(100) = ', forename, middlename'

    select *

    from dbo.TableFromList(@string)

    DECLARE @Master_Surname NVARCHAR(200)

    DECLARE @Master_Forename NVARCHAR(200)

    DECLARE @Master_MiddleName NVARCHAR(200)

    select @Master_Surname = substring(@string, 1, charindex(',', @string)-1)

    select @Master_Surname

    select @Master_Forename = substring(ltrim(replace(@string, @Master_Surname+',', '')), 1, charindex(',', (ltrim(replace(@string, @Master_Surname+',', ''))))-1)

    select @Master_Forename

    select @Master_MiddleName = reverse(left(reverse(@string), charindex(',', reverse(@string))-1))

    select @Master_MiddleName

    I will try your version now!

    ---------------------------------------------------------

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • Another one:

    declare @Word1 varchar(100), @Word2 varchar(100), @Word3 varchar(100)

    declare @STR varchar(100) = 'Word1,Word2,Word3'

    --declare @STR varchar(100) = ',Word2,'

    --declare @STR varchar(100) = ',,Word3'

    --declare @STR varchar(100) = 'Word1,,'

    --declare @STR varchar(100) = ',,'

    SELECT @Word1 = LEFT(@str, FC-1)

    ,@Word2 = SUBSTRING(@str, FC+1, SC-FC-1)

    ,@Word3 = SUBSTRING(@str, SC+1, LEN(@str))

    FROM (SELECT @STR S) Q

    CROSS APPLY (SELECT CHARINDEX(',',@str) FC) A1

    CROSS APPLY (SELECT CHARINDEX(',',@str,A1.FC+1) SC) A2

    select @Word1,@Word2,@Word3

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • That's perfect mate thanks!

    ---------------------------------------------------------

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • Actually you don't even need CROSS JOIN, I've edited my previous post...

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Curious why you wouldn't want to use a string splitter (like Jeff Moden's) for this:

    DECLARE @Word1 VARCHAR(8000), @Word2 VARCHAR(8000), @Word3 VARCHAR(8000)

    SELECT @Word1 = CASE ItemNumber WHEN 1 THEN Item ELSE @Word1 END

    ,@Word2 = CASE ItemNumber WHEN 2 THEN Item ELSE @Word2 END

    ,@Word3 = CASE ItemNumber WHEN 3 THEN Item ELSE @Word3 END

    FROM dbo.DelimitedSplit8K('Word1, Word2, Word3', ',')

    SELECT @Word1, @Word2, @Word3


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Because I'm a stupid little boy!

    Such an easy solution. Thanks mate.

    ---------------------------------------------------------

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • Abu Dina (2/5/2013)


    Because I'm a stupid little boy!

    Such an easy solution. Thanks mate.

    BWAAAHAHAHAHA!

    Actually, I thought maybe you couldn't use it because you had multiple rows like this to process.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • That is true. There are some situations where this wouldn't work well but replacing thi:

    SET @Master_Surname = LEFT(@Master_mkNormalisedName, CHARINDEX(',',@Master_mkNormalisedName)-1)

    SET @Master_Forename = LEFT(SUBSTRING(@Master_mkNormalisedName, CHARINDEX(',',@Master_mkNormalisedName)+1,

    LEN(@Master_mkNormalisedName)), CHARINDEX(',',SUBSTRING(@Master_mkNormalisedName,

    CHARINDEX(',',@Master_mkNormalisedName)+1,LEN(@Master_mkNormalisedName)))-1)

    SET @Master_MiddleName = REVERSE(LEFT(REVERSE(@Master_mkNormalisedName), CHARINDEX(',',REVERSE(@Master_mkNormalisedName))-1))

    -- get the normalised name parts and the phonetic name parts for the duplicate record

    SET @Duplicate_Surname = LEFT(@Duplicate_mkNormalisedName, CHARINDEX(',',@Duplicate_mkNormalisedName)-1)

    SET @Duplicate_Forename = LEFT(SUBSTRING(@Duplicate_mkNormalisedName, CHARINDEX(',',@Duplicate_mkNormalisedName)+1,

    LEN(@Duplicate_mkNormalisedName)), CHARINDEX(',',SUBSTRING(@Duplicate_mkNormalisedName,

    CHARINDEX(',',@Duplicate_mkNormalisedName)+1,LEN(@Duplicate_mkNormalisedName)))-1)

    SET @Duplicate_MiddleName = REVERSE(LEFT(REVERSE(@Duplicate_mkNormalisedName), CHARINDEX(',',REVERSE(@Duplicate_mkNormalisedName))-1))

    With :

    -- get the normalised name parts and the phonetic name parts for the master record

    SELECT @Master_Surname = CASE ItemNumber WHEN 1 THEN Item ELSE @Master_Surname END

    ,@Master_Forename = CASE ItemNumber WHEN 2 THEN Item ELSE @Master_Forename END

    ,@Master_MiddleName = CASE ItemNumber WHEN 3 THEN Item ELSE @Master_MiddleName END

    FROM dbo.DelimitedSplit8K(@Master_mkNormalisedName, ',')

    -- get the normalised name parts and the phonetic name parts for the duplicate record

    SELECT @Duplicate_Surname = CASE ItemNumber WHEN 1 THEN Item ELSE @Duplicate_Surname END

    ,@Duplicate_Forename = CASE ItemNumber WHEN 2 THEN Item ELSE @Duplicate_Forename END

    ,@Duplicate_MiddleName = CASE ItemNumber WHEN 3 THEN Item ELSE @Duplicate_MiddleName END

    FROM dbo.DelimitedSplit8K(@Duplicate_mkNormalisedName, ',')

    Is so much better!

    ---------------------------------------------------------

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

Viewing 10 posts - 1 through 9 (of 9 total)

You must be logged in to reply to this topic. Login to reply