February 25, 2011 at 11:19 am
Hi from a result like this
NumCodeStart DateEnd Date
204-201ABCDF2004-04-04NULL
204-203ABCDF2004-07-18NULL
204-205QWERT,ASDFG2005-12-05NULL
204-206YUIOP,GHJKL2006-05-11NULL
I wish to get this :
NumCodeStart DateEnd Date
204-201ABCDF2004-04-04NULL
204-203ABCDF2004-07-18NULL
204-205QWERT2005-12-05NULL
204-205ASDFG2005-12-05NULL
204-206YUIOP2006-05-11NULL
204-206 GHJKL2006-05-11NULL
The column that sometimes has coma seperated values are then split to creat another record with same Num, Start Date and End Date.
February 25, 2011 at 11:47 am
You need to utilize the DelimitedSplit8K function to split the delimited list apart.
You would use it like so:
SELECT Num, Item AS Code, [Start Date], [End Date]
FROM #TEST t
CROSS APPLY DelimitedSplit8K(t.Code, ',') ds
ORDER BY t.Num, ds.ItemNumber
Here is the latest version of the Delimited Split Function
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
February 25, 2011 at 3:04 pm
February 25, 2011 at 6:56 pm
Are you sure? When I run this code:
DECLARE @test-2 TABLE (Num CHAR(7), Code VARCHAR(50), [Start Date] DATETIME, [End Date] DATETIME);
INSERT INTO @test-2
SELECT '204-201','ABCDF', '2004-04-04', NULL UNION ALL
SELECT '204-203','ABCDF','2004-07-18', NULL UNION ALL
SELECT '204-205','QWERT,ASDFG','2005-12-05', NULL UNION ALL
SELECT '204-206','YUIOP,GHJKL','2006-05-11', NULL ;
SELECT Num, Item AS Code, [Start Date], [End Date]
FROM @test-2 t
CROSS APPLY DelimitedSplit8K(t.Code, ',') ds
ORDER BY t.Num, ds.ItemNumber
I get exactly the desired results:
Num Code Start Date End Date
------- ----- ----------------------- -----------------------
204-201 ABCDF 2004-04-04 00:00:00.000 NULL
204-203 ABCDF 2004-07-18 00:00:00.000 NULL
204-205 QWERT 2005-12-05 00:00:00.000 NULL
204-205 ASDFG 2005-12-05 00:00:00.000 NULL
204-206 YUIOP 2006-05-11 00:00:00.000 NULL
204-206 GHJKL 2006-05-11 00:00:00.000 NULL
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
February 27, 2011 at 5:07 pm
Could you post the code that didn't do the trick? Thanks.
--Jeff Moden
Change is inevitable... Change for the better is not.
February 28, 2011 at 11:56 am
I would also very much like to see the code that didn't work. I've been using Wayne's technique and Jeff's Delimited8KSplit for a while now and those techniques have always worked.
Todd Fifield
March 1, 2011 at 7:15 am
Hi all,
I apologize, the solution suggested by Wayne is working fine.
I made a mistake with that part of the solution (t.Code, ',') ds.
:Whistling:
March 1, 2011 at 7:56 am
infodemers (3/1/2011)
Hi all,I apologize, the solution suggested by Wayne is working fine.
I made a mistake with that part of the solution (t.Code, ',') ds.
:Whistling:
Thanks for the feedback on this... it would have been quite a shock to many people if this routine wasn't working correctly!
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply