October 22, 2012 at 2:37 pm
in my student table i have a column called as Subject,
it has values as below
Student IDSubject
101EJB;C++;PERL
102Dotnet
103Java
104Oracle;Java;Sql
105Sql;SSIS
i.e., subject column has multiple subject with separated by ;
would like to see each value (if separated by 😉 as separate columns as below
would like to see results as
Student IDSubject1 Subject2 Subject3
101EJBC++PERL
102DotnetNULLNULL
103JavaNULLNULL
104OracleJavaSql
105SqlSSISNULL
for time being just assume we have max three subjects for student
please kindly help me
Thanks in advance
asiti
October 23, 2012 at 12:09 pm
Took a shot at it...
SELECT
PARSENAME(REPLACE([Subject],';','.'),1) AS Subject1,
PARSENAME(REPLACE([Subject],';','.'),2) AS Subject2,
PARSENAME(REPLACE([Subject],';','.'),3) AS Subject3
FROM YourTable
Works with your sample data and the assumption that 3 subjects is all you'll need. If the number of subjects changes, tweaking will be necessary, but this should do for the moment.
EDIT: Gah, that's what I get for being interrupted while I'm thinking :hehe:. This reverses the order of the original input. One moment while I correct that...
- 😀
October 23, 2012 at 1:09 pm
Alright, revised it!
SELECT
ID,
PARSENAME(REPLACE([Subject],';','.'),1) AS Split1,
PARSENAME(REPLACE([Subject],';','.'),2) AS Split2,
PARSENAME(REPLACE([Subject],';','.'),3) AS Split3
INTO #SplitTable
FROM YourTable
SELECT ID,
CASE WHEN Split2 IS NULL AND Split3 IS NULL THEN Split1
WHEN Split3 IS NULL THEN Split2
ELSE Split3 END AS Subject1,
CASE WHEN Split2 IS NULL AND Split3 IS NULL THEN NULL
WHEN Split3 IS NULL THEN Split1
ELSE Split2 END AS Subject2,
CASE WHEN Split3 IS NULL THEN NULL
ELSE Split1 END AS Subject3 FROM #temp2
DROP TABLE #SplitTable
Ugh. This probably wasn't the best way to do this, and it feels kinda inelegant. On a million-row test harness, it works out acceptably in execution speed, but the splitter table would most certainly be more elegant and a lot more efficient. This reminded me of a problem I had to solve myself at some point, but the finer details were a bit more convoluted than I'd hoped.
- 😀
October 23, 2012 at 2:29 pm
That's why I recommended the Splitter. It gives a much simpler and more understandable code.
I could help with the code, but Asiti should read the articles first.
October 23, 2012 at 3:08 pm
Luis Cazares (10/23/2012)
That's why I recommended the Splitter. It gives a much simpler and more understandable code.I could help with the code, but Asiti should read the articles first.
I will help Asiti out and post some nice consumable data however i agree with Luis that Asiti should read the articles. DelimitedSplit8k is the way to go to perform the split but i went with a pivot table instead of cross tabs. (accomplishes the same thing just different way it works in the background.)
;WITH data AS (
SELECT 101 AS StudentID, 'EJB;C++;PERL' AS Subject UNION ALL
SELECT 102,'Dotnet' UNION ALL
SELECT 103,'Java' UNION ALL
SELECT 104,'Oracle;Java;Sql' UNION ALL
SELECT 105,'Sql;SSIS')
For performance Issues see how we like them posted here: How to Post Performance Problems - Gail Shaw[/url]
Need to Split some strings? Jeff Moden's DelimitedSplit8K[/url]
Jeff Moden's Cross tab and Pivots Part 1[/url]
Jeff Moden's Cross tab and Pivots Part 2[/url]
October 24, 2012 at 6:42 pm
Here's how to make your query using Jeff Moden's splitter function (of which a slightly modified version is shown below):
IF OBJECT_ID('tempdb..#TempTable') IS NOT NULL
DROP TABLE #TempTable
CREATE TABLE #TempTable (
[RowNum] INT IDENTITY(1,1),
[StudentID] INT NOT NULL,
[Subj] NVARCHAR(50) NULL,
PRIMARY KEY (RowNum))
INSERT INTO #TempTable SELECT 101,'EJB;C++;PERL'
INSERT INTO #TempTable SELECT 102,'Dotnet'
INSERT INTO #TempTable SELECT 103,'Java'
INSERT INTO #TempTable SELECT 104,'Oracle;Java;Sql'
INSERT INTO #TempTable SELECT 105,'Sql;SSIS'
DECLARE
@strInput VARCHAR(8000)
,@Delimiter1 CHAR(1)
,@Delimiter2 CHAR(1)
,@Delimiter3 CHAR(1)
SET @Delimiter1 = '|'
SET @Delimiter2 = ','
SET @Delimiter3 = ';'
SELECT
@strInput = REPLACE(COALESCE(@strInput+@Delimiter1,'')
+CAST(CAST(t.StudentID AS VARCHAR(5))
+@Delimiter2+t.Subj AS VARCHAR(MAX)),@Delimiter3,@Delimiter2)
FROM
#TempTable AS t
SELECT
StudentID = (MAX(CASE c.itemnumber WHEN 1 THEN c.item END))
,Subj1 = (MAX(CASE c.itemnumber WHEN 2 THEN c.item END))
,Subj2 = (MAX(CASE c.itemnumber WHEN 3 THEN c.item END))
,Subj3 = (MAX(CASE c.itemnumber WHEN 4 THEN c.item END))
FROM
(
SELECT
@strInput
) a (parameter)
CROSS APPLY
dbo.tvfDelimitedSplit(parameter,@Delimiter1) b
CROSS APPLY
dbo.tvfDelimitedSplit(item,@Delimiter2) c
GROUP BY
b.ItemNumber
The code above requires Jeff Moden's splitter function (and this version requires a separate Tally table as well).
LINK: The "Numbers" or "Tally" Table: What it is and how it replaces a loop[/url] will show you how to create your own Tally table--very easy.
CREATE FUNCTION dbo.tvfDelimitedSplit
(
@pString VARCHAR(8000)
,@pDelimiter CHAR(1)
)
RETURNS TABLE
WITH SCHEMABINDING
AS
RETURN
WITH
cteTally(N)
AS
(
SELECT TOP (ISNULL(DATALENGTH(@pString),0))
ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM
dbo.Tally
)
,cteStart(N1)
AS
(
SELECT
1
UNION ALL
SELECT
t.N + 1
FROM
cteTally t
WHERE
SUBSTRING(@pString,t.N,1) = @pDelimiter
)
,cteLen(N1,L1)
AS
(
SELECT
s.N1
,ISNULL(
NULLIF(
CHARINDEX(@pDelimiter,@pString,s.N1),0)
- s.N1,8000)
FROM
cteStart s
)
SELECT
ItemNumber = ROW_NUMBER() OVER (ORDER BY l.N1)
,Item = SUBSTRING(@pString,l.N1,l.L1)
FROM
cteLen l;
Output:
StudentID Subj1 Subj2 Subj3
101 EJB C++ PERL
102 Dotnet NULL NULL
103 Java NULL NULL
104 Oracle Java Sql
105 Sql SSIS NULL
October 24, 2012 at 7:03 pm
Since the OP seems to have disappeared ill post the code.
;WITH data AS (
SELECT 101 AS StudentID, 'EJB;C++;PERL' AS Subject UNION ALL
SELECT 102,'Dotnet' UNION ALL
SELECT 103,'Java' UNION ALL
SELECT 104,'Oracle;Java;Sql' UNION ALL
SELECT 105,'Sql;SSIS')
SELECT StudentID, [1],[2],[3]
FROM
(
SELECT StudentID, ItemNumber, Item
FROM data
CROSS APPLY udf_DelimitedSplit8K (Subject,';')
)p
PIVOT
(
MAX(Item)
FOR ItemNumber IN ([1],[2],[3])
)pvt
we dont need the extra delimiters since the pivot table takes care of adding our nulls. also the original version of jeffs splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/ is probably the most optimized version of it. by using a CTE to build the tally table in memory we ensure that (unless its paged to disk) we have our numbers table in memory and dont have any reads from disk (again baring the engine using tempdb which we have no control over other than adding more memory to our server).
and for the cross tabs we can do the following and still only need the one delimiter
;WITH data AS (
SELECT 101 AS StudentID, 'EJB;C++;PERL' AS Subject UNION ALL
SELECT 102,'Dotnet' UNION ALL
SELECT 103,'Java' UNION ALL
SELECT 104,'Oracle;Java;Sql' UNION ALL
SELECT 105,'Sql;SSIS')
SELECT StudentID, MAX(CASE WHEN ItemNumber = 1 THEN Item ELSE NULL END),
MAX(CASE WHEN ItemNumber = 2 THEN Item ELSE NULL END),
MAX(CASE WHEN ItemNumber = 3 THEN Item ELSE NULL END)
FROM(
SELECT StudentID, ItemNumber, Item
FROM data
CROSS APPLY udf_DelimitedSplit8K (Subject,';'))x
GROUP BY StudentID
For performance Issues see how we like them posted here: How to Post Performance Problems - Gail Shaw[/url]
Need to Split some strings? Jeff Moden's DelimitedSplit8K[/url]
Jeff Moden's Cross tab and Pivots Part 1[/url]
Jeff Moden's Cross tab and Pivots Part 2[/url]
October 26, 2012 at 9:12 am
Thanks for all the man kind
i great full to al of you
hisakimatama
Luis Cazares
capnhector
Steven Willis
i got the answer from hisakimatama, when he gave his first reply, i am using it, today i just turn up to forum, i felt very happy for the posts,
i greatful to you all
thanks for helping
Best regards
October 26, 2012 at 10:37 am
asita (10/26/2012)
Thanks for all the man kindi great full to al of you
hisakimatama
Luis Cazares
capnhector
Steven Willis
i got the answer from hisakimatama, when he gave his first reply, i am using it, today i just turn up to forum, i felt very happy for the posts,
i greatful to you all
thanks for helping
Best regards
as Luis C. pointed out about hisakimatama's solution uses PARSENAME which only works with up to 4 elements (http://msdn.microsoft.com/en-us/library/ms188006.aspx) if you ever need to go over 4 or go dynamic you will need to use either a cross tab or pivot table.
For performance Issues see how we like them posted here: How to Post Performance Problems - Gail Shaw[/url]
Need to Split some strings? Jeff Moden's DelimitedSplit8K[/url]
Jeff Moden's Cross tab and Pivots Part 1[/url]
Jeff Moden's Cross tab and Pivots Part 2[/url]
Viewing 10 posts - 1 through 9 (of 9 total)
You must be logged in to reply to this topic. Login to reply