September 19, 2013 at 2:49 am
Hi All,
I have table called T1 where the data is populated like below
LineNumber errortext Fileid
1 a 10
1 b 10
2 a 11
2 b 11
2 c 11
3 c 12
3 d 12
Now I have a table called t2 with same structure. Now I want to insert the records into t2 table and the data should be coming from T1 table. where the id is same it will take one id and one linenumber and concatenate of errortext field. My output will be like below
LineNumber errortext Fileid
1 a,b 10
2 a,b,c 11
3 c,d 12
File id should be taken once and then distinct of linenumber field and then concatenate of errortext field.
Thanks in advance for your help!!
September 19, 2013 at 3:18 am
Quick and dirty solution which would not scale that well but works as below. You may want to investigate
CLR concatenate aggregate[/url]
declare @a table (Linenumber int, ErrorText varchar(30),FileID int)
insert into @a values
(1, 'a', 10),
(1, 'b', 10),
(2, 'a', 11),
(2, 'b', 11),
(2, 'c', 11),
(3, 'c', 12),
(3, 'd', 12)
select * from @a
declare @FileID int, @LineNumber int
declare FileIDCursor cursor for select distinct FileID, LineNumber from @a
declare @AggResult table (LineNumber int, ErrorText varchar(1000), FileID int)
open FileIDCursor
fetch next from FileIDCursor into @FileID, @LineNumber
while @@FETCH_STATUS = 0
begin
declare @Concat varchar(1000) = ''
select @Concat = @Concat + ErrorText + ','
from @a
where FileID = @FileID and linenumber = @LineNumber
insert into @AggResult
select @LineNumber, left(@Concat,len(@Concat)-1), @FileID
fetch next from FileIDCursor into @FileID, @LineNumber
end
close FileIDCursor
deallocate FileIDCursor
select * from @AggResult
Fitz
September 19, 2013 at 3:54 am
September 19, 2013 at 5:41 am
Thanks guys for your input
It is working awesome!!
September 19, 2013 at 7:40 am
There is no need to resort to looping for this. You can instead use STUFF.
Thanks Mark for the ddl and sample data.
declare @a table (Linenumber int, ErrorText varchar(30),FileID int)
insert into @a values
(1, 'a', 10),
(1, 'b', 10),
(2, 'a', 11),
(2, 'b', 11),
(2, 'c', 11),
(3, 'c', 12),
(3, 'd', 12)
select Linenumber,
STUFF((select ',' + ErrorText
from @a a2
where a1.Linenumber = a2.Linenumber
order by a2.ErrorText
for xml path('')), 1, 1, '') as ErrorTexts
, FileID
from @a a1
group by Linenumber, FileID
_______________________________________________________________
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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
September 19, 2013 at 10:18 pm
niladri.primalink (9/19/2013)
Thanks guys for your inputIt is working awesome!!
"It"? What is "It"? What did you end up using? Please post the code that you ended up using.
--Jeff Moden
Change is inevitable... Change for the better is not.
September 20, 2013 at 12:28 am
Sorry For using the word 'it'.
Actually the code what SScrazy sent to me is working for me.
That's why I wrote it is working for me.
If I hurt you then it is in my unbeknown.
September 20, 2013 at 1:10 am
I think what Jeff is getting at, and I agree, is that you shouldn't necessary use the first solution you're given. Mark himself admitted that it's "quick and dirty" and that it won't work very well once your table starts to grow; he even suggested another method. I linked to an article that shows you half a dozen or so ways of doing it. I recommend you evaluate them all to see which works best. Yes, it's more work for you now, but it'll pay in terms of future performance and and of how well prepared you'll be next time you have to implement something like this.
John
September 21, 2013 at 10:46 am
niladri.primalink (9/20/2013)
Sorry For using the word 'it'.Actually the code what SScrazy sent to me is working for me.
That's why I wrote it is working for me.
If I hurt you then it is in my unbeknown.
Thank you for the concern but you didn't hurt me. I'm more concerned about what you ended up using because While Loops and cursors can be quite slow. That's why I wanted to know what you ended up using.
My recommendation would be to have a look at the code that Sean wrote for this. With apologies to Mark, Sean's code will run much more quickly.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply