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

Help needed Expand / Collapse
Author
Message
Posted Wednesday, June 18, 2014 5:40 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Friday, August 8, 2014 8:15 AM
Points: 69, Visits: 293
create table #temp (id int, data varchar(80))

insert into #temp (id, data)

select 1, 'a,b,c'
union all
select 2, 'x,y'
union all

select 3,'j,k,l'

select * from #temp

i want to create a output like this.

1 a
1 b
1 c
2 x
2 y
3 j
3 k
3 l


wanted to create table with above desired result.


the values in second column is comma separated value.

please help me with possible solution.
Post #1582833
Posted Wednesday, June 18, 2014 5:44 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 11:26 AM
Points: 13,622, Visits: 10,514
The best function there is to find:

Tally OH! An Improved SQL 8K “CSV Splitter” Function




How to post forum questions.
Need an answer? No, you need a question.
What’s the deal with Excel & SSIS?

Member of LinkedIn. My blog at LessThanDot.

MCSA SQL Server 2012 - MCSE Business Intelligence
Post #1582835
Posted Thursday, June 19, 2014 11:10 AM


SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Thursday, August 21, 2014 11:49 AM
Points: 224, Visits: 338
raghava_tg (6/18/2014)
create table #temp (id int, data varchar(80))

insert into #temp (id, data)

select 1, 'a,b,c'
union all
select 2, 'x,y'
union all

select 3,'j,k,l'

select * from #temp

i want to create a output like this.

1 a
1 b
1 c
2 x
2 y
3 j
3 k
3 l


wanted to create table with above desired result.


the values in second column is comma separated value.

please help me with possible solution.


One way to do this would be with a table-valued function such as this, which uses XML to parse through your comma-separated list:
CREATE FUNCTION dbo.comma_split (@input_string VARCHAR(MAX))
RETURNS @Result TABLE(Value VARCHAR(25))
AS
BEGIN
DECLARE @x XML
SELECT @x = CAST('<A>'+ REPLACE(@input_string,',','</A><A>')+ '</A>' AS XML)

INSERT INTO @Result
SELECT t.value('.', 'char') AS inVal
FROM @x.nodes('/A') AS x(t)

RETURN
END
GO

From here, you can call the function like this
SELECT
TMP.id,
CSD.Value
FROM #temp TMP
CROSS APPLY dbo.comma_split(TMP.data) CSD
:
Post #1583981
Posted Thursday, June 19, 2014 11:52 AM
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: 2 days ago @ 1:00 PM
Points: 4,196, Visits: 3,235
Koen is right - Jeff Moden's DelimitedSplit8K function is the best approach I've seen for this. If you haven't read about it yet, its well worth the time. Be forewarned, it will change the way you look at strings and change your expectations of performance.

Once you implement the function, here's how to accomplish exactly what you're trying to do:

SELECT t.id, s.item
FROM #temp t
CROSS APPLY DelimitedSplit8K(data, ',') s
ORDER BY t.id, s.item;




Tally Tables - Performance Personified
String Splitting with True Performance
Best practices on how to ask questions
Post #1584000
Posted Thursday, June 19, 2014 12:45 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:32 PM
Points: 13,302, Visits: 12,168
Ed Pollack (6/19/2014)
raghava_tg (6/18/2014)
create table #temp (id int, data varchar(80))

insert into #temp (id, data)

select 1, 'a,b,c'
union all
select 2, 'x,y'
union all

select 3,'j,k,l'

select * from #temp

i want to create a output like this.

1 a
1 b
1 c
2 x
2 y
3 j
3 k
3 l


wanted to create table with above desired result.


the values in second column is comma separated value.

please help me with possible solution.


One way to do this would be with a table-valued function such as this, which uses XML to parse through your comma-separated list:
CREATE FUNCTION dbo.comma_split (@input_string VARCHAR(MAX))
RETURNS @Result TABLE(Value VARCHAR(25))
AS
BEGIN
DECLARE @x XML
SELECT @x = CAST('<A>'+ REPLACE(@input_string,',','</A><A>')+ '</A>' AS XML)

INSERT INTO @Result
SELECT t.value('.', 'char') AS inVal
FROM @x.nodes('/A') AS x(t)

RETURN
END
GO

From here, you can call the function like this
SELECT
TMP.id,
CSD.Value
FROM #temp TMP
CROSS APPLY dbo.comma_split(TMP.data) CSD
:


Ed you should take a look at the DelimitedSplit8K function. It is way faster than the xml style splitter.


_______________________________________________________________

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 #1584030
Posted Thursday, June 19, 2014 12:47 PM


SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Thursday, August 21, 2014 11:49 AM
Points: 224, Visits: 338
Sean Lange (6/19/2014)
Ed Pollack (6/19/2014)
raghava_tg (6/18/2014)
create table #temp (id int, data varchar(80))

insert into #temp (id, data)

select 1, 'a,b,c'
union all
select 2, 'x,y'
union all

select 3,'j,k,l'

select * from #temp

i want to create a output like this.

1 a
1 b
1 c
2 x
2 y
3 j
3 k
3 l


wanted to create table with above desired result.


the values in second column is comma separated value.

please help me with possible solution.


One way to do this would be with a table-valued function such as this, which uses XML to parse through your comma-separated list:
CREATE FUNCTION dbo.comma_split (@input_string VARCHAR(MAX))
RETURNS @Result TABLE(Value VARCHAR(25))
AS
BEGIN
DECLARE @x XML
SELECT @x = CAST('<A>'+ REPLACE(@input_string,',','</A><A>')+ '</A>' AS XML)

INSERT INTO @Result
SELECT t.value('.', 'char') AS inVal
FROM @x.nodes('/A') AS x(t)

RETURN
END
GO

From here, you can call the function like this
SELECT
TMP.id,
CSD.Value
FROM #temp TMP
CROSS APPLY dbo.comma_split(TMP.data) CSD
:


Ed you should take a look at the DelimitedSplit8K function. It is way faster than the xml style splitter.


There's a bunch of fun ways to do this and in this one case I went explicitly for the shortest, quickest, and dirtiest Not the least efficient way to do it, but an example of an alternative that's good for non-huge data sets.
Post #1584032
Posted Thursday, June 19, 2014 12:50 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:32 PM
Points: 13,302, Visits: 12,168
Ed Pollack (6/19/2014)
There's a bunch of fun ways to do this and in thios one case I went explicitly for the shortest, quickest, and dirtiest Not the least efficient way to do it, but an example of an alternative that's good for non-huge data sets.


I guess we will have to agree to disagree on this. The problem with this type of mindset for me is that when somebody uses a less efficient method and it works in one case because the dataset is small they will often use that same method on a large dataset and suddenly they have performance issues. With such a super fast function readily available why not make that the go to?


_______________________________________________________________

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 #1584036
Posted Thursday, June 19, 2014 1:00 PM


SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Thursday, August 21, 2014 11:49 AM
Points: 224, Visits: 338
Sean Lange (6/19/2014)
Ed Pollack (6/19/2014)
There's a bunch of fun ways to do this and in thios one case I went explicitly for the shortest, quickest, and dirtiest Not the least efficient way to do it, but an example of an alternative that's good for non-huge data sets.


I guess we will have to agree to disagree on this. The problem with this type of mindset for me is that when somebody uses a less efficient method and it works in one case because the dataset is small they will often use that same method on a large dataset and suddenly they have performance issues. With such a super fast function readily available why not make that the go to?


No one method is always 100% faster, and in a case like this I'd have to ask if this is a one-off or maintenance service, or is it a huge production table with millions of rows of this stuff being processed constantly? If it's the latter, I'd jump up and ask why we are doing this? SQL Server isn't very good at string manipulation and we are trying hard to make it grind through strings anyway.

If I saw this in a production environment, my first question would be why are we storing CSV data like this and why is SQL Server being tasked with dealing with it? There are certainly valid use cases for storing CSV data in the database---user settings, variable-length lists of random stuff, data to display directly, etc...but those are scenarios where the application will deal with displaying the data or parsing it (before it hits SQL Server).

Jeff's article is excellent, and does a very good job of putting together a case for the best way to do this---but I'd always start off by asking why we are doing this in the first place. Sometimes the truly best solution to a problem is to change the question
Post #1584040
Posted Thursday, June 19, 2014 1:09 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:32 PM
Points: 13,302, Visits: 12,168
Ed Pollack (6/19/2014)
Sean Lange (6/19/2014)
Ed Pollack (6/19/2014)
There's a bunch of fun ways to do this and in thios one case I went explicitly for the shortest, quickest, and dirtiest Not the least efficient way to do it, but an example of an alternative that's good for non-huge data sets.


I guess we will have to agree to disagree on this. The problem with this type of mindset for me is that when somebody uses a less efficient method and it works in one case because the dataset is small they will often use that same method on a large dataset and suddenly they have performance issues. With such a super fast function readily available why not make that the go to?


No one method is always 100% faster, and in a case like this I'd have to ask if this is a one-off or maintenance service, or is it a huge production table with millions of rows of this stuff being processed constantly? If it's the latter, I'd jump up and ask why we are doing this? SQL Server isn't very good at string manipulation and we are trying hard to make it grind through strings anyway.

If I saw this in a production environment, my first question would be why are we storing CSV data like this and why is SQL Server being tasked with dealing with it? There are certainly valid use cases for storing CSV data in the database---user settings, variable-length lists of random stuff, data to display directly, etc...but those are scenarios where the application will deal with displaying the data or parsing it (before it hits SQL Server).

Jeff's article is excellent, and does a very good job of putting together a case for the best way to do this---but I'd always start off by asking why we are doing this in the first place. Sometimes the truly best solution to a problem is to change the question


I agree that somebody who is seasoned would look at this a bit different. The OP does not seem to have the kind of prowess and comfort that other may possess. While it is true that no single method will always be the best choice, or fastest, it was basically proven in that article that the xml style splitter is the slowest until you get quite a few elements per row (right about 40). Even then it is consistently far slower.


Sometimes the truly best solution to a problem is to change the question


I couldn't agree more!!!


_______________________________________________________________

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 #1584047
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse