Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Split a pipe delimited string into two columns Expand / Collapse
Author
Message
Posted Thursday, March 6, 2014 12:57 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, March 14, 2014 9:21 AM
Points: 1, Visits: 71
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!
Post #1548441
Posted Thursday, March 6, 2014 1:10 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 9:10 AM
Points: 13,230, Visits: 12,709
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 Moden's 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)
Post #1548449
Posted Thursday, March 6, 2014 2:47 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, October 31, 2014 6:31 AM
Points: 107, Visits: 514
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')

Post #1548506
Posted Thursday, March 6, 2014 5:54 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Monday, November 24, 2014 4:53 AM
Points: 3,422, Visits: 5,368
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!
Post #1548548
Posted Friday, March 7, 2014 6:48 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, October 31, 2014 6:31 AM
Points: 107, Visits: 514
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!"
Post #1548716
Posted Friday, March 7, 2014 5:07 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 8:51 PM
Points: 35,606, Visits: 32,190
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1548932
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse