Author |
Topic |
madhivanan
Premature Yak Congratulator
22864 Posts |
Posted - 2006-04-27 : 05:55:14
|
If the table is denormalised and has Comma Seperate Values in a column, this code will copy it to Multiple columns of a Normalised tabledeclare @DeNormalisedTable table(data varchar(8000))insert into @DeNormalisedTable select '1,Davolio,Nancy' union allselect '2,Fuller,Andrew' union allselect '3,Leverling,Janet' union allselect '4,Peacock,Margaret' union allselect '5,Buchanan,Steven' union allselect '6,Suyama,Michael' union allselect '7,King,Robert' union allselect '8,Callahan,Laura' union allselect '9,Dodsworth,Anne'select * from @DeNormalisedTable -- Comma Seperated Valuesdeclare @s varchar(8000), @data varchar(8000)Create table #NormalisedTable (Code int, FirstName varchar(100), LastName varchar(100))select @s=''while exists (Select * from @DeNormalisedTable where data>@s)Begin Select @s=min(data) from @DeNormalisedTable where data>@s select @data=''''+replace(@s,',',''',''')+'''' insert into #NormalisedTable exec('select '+@data)Endselect * from #NormalisedTable -- Data in Normalised Tabledrop table #NormalisedTable MadhivananFailing to plan is Planning to fail |
|
RyanRandall
Master Smack Fu Yak Hacker
1074 Posts |
Posted - 2006-04-27 : 06:53:10
|
Nice work Madhivanan - very neat Here's a link (for others) to the usual alternatives to this sort of problem...http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=55210&SearchTerms=CSV,Splitting%20delimited%20lists,Best%20split%20functionsAnd here's one of those techniques applied to this example (adjusted slightly)...--datadeclare @DeNormalisedTable table(data varchar(8000), Code int, FirstName varchar(100), LastName varchar(100))insert into @DeNormalisedTable (data)select '1,Davolio,Nancy' union allselect '2,Fuller,Andrew' union allselect '3,Leverling,Janet' union allselect '4,Peacock,Margaret' union allselect '5,Buchanan,Steven' union allselect '6,Suyama,Michael' union allselect '7,King,Robert' union allselect '8,Callahan,Laura' union allselect '9,Dodsworth,Anne'--calculationdeclare @i int, @j int, @k intupdate @DeNormalisedTable set @i = charindex(',', data), Code = left(data, @i-1), @j = charindex(',', data + ',', @i+1), FirstName = substring(data, @i+1, @j-@i-1), @k = charindex(',', data + ',', @j+1), LastName = substring(data, @j+1, @k-@j-1)select * from @DeNormalisedTable Ryan Randallwww.monsoonmalabar.com London-based IT consultancy Solutions are easy. Understanding the problem, now, that's the hard part. |
|
|
madhivanan
Premature Yak Congratulator
22864 Posts |
Posted - 2006-04-27 : 09:08:45
|
Thanks Ryan. Your method is more simpler than mine MadhivananFailing to plan is Planning to fail |
|
|
spirit1
Cybernetic Yak Master
11752 Posts |
Posted - 2006-04-27 : 10:20:59
|
http://weblogs.sqlteam.com/mladenp/archive/2005/08/01/7421.aspxpoint 8Go with the flow & have fun! Else fight the flow Blog thingie: [URL="http://weblogs.sqlteam.com/mladenp"] |
|
|
madhivanan
Premature Yak Congratulator
22864 Posts |
Posted - 2006-04-27 : 11:03:45
|
Thanks Mladen. Both of yours and Ryan's are more effecient MadhivananFailing to plan is Planning to fail |
|
|
|
|
|