SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Split a pipe delimited string into two columns


Split a pipe delimited string into two columns

Author
Message
Moe_Szyslak
Moe_Szyslak
Forum Newbie
Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)

Group: General Forum Members
Points: 7 Visits: 88
Hello all,

I have a single string "XYZ00001|Test_b|XYZ00002|Test_a|XYZ00003|Test_c" that will continue to grow over time.

Is there a way I can extract the values from the string into two separate columns?

XYZ0001 Test_b
XYZ0002 Test_a
XYZ0003 Test_c

Any advice or suggestions is appreciated. Thanks in advance!
Sean Lange
Sean Lange
SSC Guru
SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)SSC Guru (63K reputation)

Group: General Forum Members
Points: 63939 Visits: 17974
Moe_Szyslak (3/6/2014)
Hello all,

I have a single string "XYZ00001|Test_b|XYZ00002|Test_a|XYZ00003|Test_c" that will continue to grow over time.

Is there a way I can extract the values from the string into two separate columns?

XYZ0001 Test_b
XYZ0002 Test_a
XYZ0003 Test_c

Any advice or suggestions is appreciated. Thanks in advance!


Sure start by looking at the link in my signature about splitting strings.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
lnardozi 61862
lnardozi 61862
Old Hand
Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)

Group: General Forum Members
Points: 395 Visits: 617
Moden's string splitter (or any string splitter) can be used in this manner:



SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE FUNCTION TVF_2col
(
@col varchar(8000)
)
RETURNS TABLE
AS
RETURN
(
select a.item ky,b.item val from
[dbo].[DelimitedSplit8K](@col,'|') a
inner join
[dbo].[DelimitedSplit8K](@col,'|') b on b.itemnumber = a.itemnumber +1 and a.itemnumber % 2 =1
)
GO
select * from tvf_2col('XYZ00001|Test_b|XYZ00002|Test_a|XYZ00003|Test_c')


dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18199 Visits: 6431
There's no reason to call DelimitedSplit8K twice, even if it is super-efficient (bless its heart):


WITH SampleData (s) AS
(
SELECT 'XYZ00001|Test_b|XYZ00002|Test_a|XYZ00003|Test_c'
)
SELECT s
,Col1=MAX(CASE WHEN ItemNumber%2 = 1 THEN Item END)
,Col2=MAX(CASE WHEN ItemNumber%2 = 0 THEN Item END)
FROM SampleData
CROSS APPLY dbo.DelimitedSplit8K(s, '|')
GROUP BY s, (1+ItemNumber)/2;





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
lnardozi 61862
lnardozi 61862
Old Hand
Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)

Group: General Forum Members
Points: 395 Visits: 617
Dwain,

I bow before the majesty of your CASE / GROUP BY logic. I couldn't figure out how to do it without a temp table.
As my neighbor would say, "that's slicker 'n' own snot!"
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (219K reputation)SSC Guru (219K reputation)SSC Guru (219K reputation)SSC Guru (219K reputation)SSC Guru (219K reputation)SSC Guru (219K reputation)SSC Guru (219K reputation)SSC Guru (219K reputation)

Group: General Forum Members
Points: 219228 Visits: 42002
dwain.c (3/6/2014)
There's no reason to call DelimitedSplit8K twice, even if it is super-efficient (bless its heart):


WITH SampleData (s) AS
(
SELECT 'XYZ00001|Test_b|XYZ00002|Test_a|XYZ00003|Test_c'
)
SELECT s
,Col1=MAX(CASE WHEN ItemNumber%2 = 1 THEN Item END)
,Col2=MAX(CASE WHEN ItemNumber%2 = 0 THEN Item END)
FROM SampleData
CROSS APPLY dbo.DelimitedSplit8K(s, '|')
GROUP BY s, (1+ItemNumber)/2;




+1000 Excellent.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search