December 28, 2009 at 10:11 am
Hi All,
I am trying to optimize some code which basically creates a table variable, selects some values into it and then loops through the table to concatenate values into a single variable. It basically builds some XML.
This code is not performing all that well and i thought i may be able to optimize this using recursive XML. I was hoping something like this may work but unfortunately its not. WITH cat AS (
SELECT CategoryNo,
Headline
FROM Association a,
Category c
WHERE a.Tag = 'Clip' + @ClipId
AND a.ParentType = 'C'
AND a.ParentNo = c.CategoryNo
UNION ALL
SELECT @categories = @categories + '<category><id>' + CategoryNo
+ '</id><name><![CDATA[' + Headline + ']]></name></category>'
FROM cat
)
Does anybody have any suggestions? I can post the old code if you feel it may help.
Thank you all in advance,
Paul
December 28, 2009 at 10:18 am
Will something like this work?
/*
Multi-row string concat using XML and string functions.
Pretty slick trick. Got it from RBarryYoung and Lynn Pettis on SSC.
*/
if object_id(N'tempdb..#T') is not null
drop table #T;
create table #T (
ID int identity primary key,
SetID int not null,
Val varchar(100));
insert into #T (SetID, Val)
select 1, 'a' union all
select 1, 'b' union all
select 2, '1' union all
select 2, '2' union all
select 3, 'a<b' union all
select 3, 'c>b';
select distinct
SetID,
stuff( -- Gets rid of leading comma
(select ', ' + Val -- No column name gets rid of that part in the XML
from #T t2
where t2.SetID = t1.SetID
for xml
path(''), -- ('') gets rid of row tags
TYPE).value('.[1]', 'varchar(MAX)') -- value query allows XML characters
,1,2,'') -- part of Stuff statement
from
#T t1;
- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread
"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
December 28, 2009 at 11:49 am
I'm having some trouble getting all of the elements into on long string. Maybe it will help if I post the code that I am trying to optimize. Your solution may work it may just be me having an issue wrapping my head around it. Thanks again!!!
DECLARE @table TABLE
(
rownum INT IDENTITY(1, 1)
PRIMARY KEY
NOT NULL,
CategoryNo INT,
Headline VARCHAR(100)
)
DECLARE @categories VARCHAR(MAX)
DECLARE @tempval1 VARCHAR(50)
DECLARE @tempval2 VARCHAR(1000)
DECLARE @rowcnt INT
DECLARE @maxrows INT
--- Get all the categories for the clip
INSERT @table
SELECT CategoryNo,
Headline
FROM Association a,
Category c
WHERE a.Tag = 'Clip' + @ClipId
AND a.ParentType = 'C'
AND a.ParentNo = c.CategoryNo
SELECT @maxrows = COUNT(*)
FROM @table
SELECT @rowcnt = 1
--- Set category xml start tag
SELECT @categories = '<CategoryList>'
--- Construct category XML for the clip
WHILE @rowcnt <= @maxrows
BEGIN
SELECT @tempval1 = Headline,
@tempval2 = CategoryNo
FROM @table
WHERE rownum = @rowcnt
SET @categories = @categories + '<category><id>' + @tempval2
+ '</id><name><![CDATA[' + @tempval1 + ']]></name></category>'
SELECT @rowcnt = @rowcnt + 1
END
--- Set category xml closing tag
SET @categories = @categories + '</CategoryList>'
December 30, 2009 at 7:24 am
Is there a reason you're not just using the For XML clause on a select query? That would do what you're looking for, and would do it much more easily and faster.
- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread
"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
December 30, 2009 at 7:34 am
I have honestly never used it before. Ill do some research and restructure the code. Thank you for the suggestion.
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply