July 20, 2017 at 4:00 am
Hi,
my Cross-Apply returns multiple Values. How can i bring these Values to 1 String (V1,V2,V3....) into my MainSelect?
SELECT distinct
a.[NAME]
,c.OBJEKTID -- multiple Values-String
FROM [Devices] a
cross apply
(
Select objektid from [Devices] b
where a.OBJEKTID = b.OBJEKTID
) c
Data
Name OBJEKTID
d100 1001
d100 1002
d100 1003
d100 1004
d101 1011
d101 1012
Result
d100 1001,1002,1003,1004
d101 1011,1012
Regards
Nicole
:ermm:
July 20, 2017 at 4:12 am
Nicole
With no DDL or sample data, it's difficult to visualise. But if you type "concatenate for xml" into your favourite search engine, you should get plenty of results that explain a technique to concatenate multiple rows into one.
John
July 20, 2017 at 5:30 am
info 58414 - Thursday, July 20, 2017 4:00 AMHi,
my Cross-Apply returns multiple Values. How can i bring these Values to 1 String (V1,V2,V3....) into my MainSelect?SELECT distinct
a.[NAME]
,c.OBJEKTID -- multiple Values-String
FROM [Devices] a
cross apply
(
Select objektid from [Devices] b
where a.OBJEKTID = b.OBJEKTID
) cData
Name OBJEKTID
d100 1001
d100 1002
d100 1003
d100 1004
d101 1011
d101 1012Result
d100 1001,1002,1003,1004
d101 1011,1012Regards
Nicole
:ermm:
You could try something like thisSELECT
a.[NAME]
, OBJEKTID = LTRIM(RTRIM(
STUFF(
( SELECT ',' + CAST(b.OBJEKTID AS VARCHAR(10))
FROM [Devices] b
WHERE a.[NAME] = b.[NAME]
GROUP BY b.OBJEKTID
ORDER BY b.OBJEKTID
FOR XML PATH(''), TYPE).value('(./text())[1]','VARCHAR(MAX)'
), 1, 1, '')
))
FROM [Devices] a
GROUP BY a.[NAME]
ORDER BY a.[NAME]
July 20, 2017 at 7:30 am
DesNorton - Thursday, July 20, 2017 5:29 AMinfo 58414 - Thursday, July 20, 2017 4:00 AMHi,
my Cross-Apply returns multiple Values. How can i bring these Values to 1 String (V1,V2,V3....) into my MainSelect?SELECT distinct
a.[NAME]
,c.OBJEKTID -- multiple Values-String
FROM [Devices] a
cross apply
(
Select objektid from [Devices] b
where a.OBJEKTID = b.OBJEKTID
) cData
Name OBJEKTID
d100 1001
d100 1002
d100 1003
d100 1004
d101 1011
d101 1012Result
d100 1001,1002,1003,1004
d101 1011,1012Regards
Nicole
:ermm:You could try something like this
SELECT
a.[NAME]
, OBJEKTID = LTRIM(RTRIM(
STUFF(
( SELECT ',' + CAST(b.OBJEKTID AS VARCHAR(10))
FROM [Devices] b
WHERE a.[NAME] = b.[NAME]
GROUP BY b.OBJEKTID
ORDER BY b.OBJEKTID
FOR XML PATH(''), TYPE).value('(./text())[1]','VARCHAR(MAX)'
), 1, 1, '')
))
FROM [Devices] a
GROUP BY a.[NAME]
ORDER BY a.[NAME]
This is good. Since the OP is concatenating numbers, however, you could lose the ", TYPE" and "value('(./text())[1]','VARCHAR(MAX)' )"
That code prevents special XML characters such as "<>&" from messing up your result set but slows the query performance. The OP is not returning any XML characters so the performance hit is not necessary.
-- Itzik Ben-Gan 2001
July 20, 2017 at 12:00 pm
Alan.B - Thursday, July 20, 2017 7:30 AMThis is good. Since the OP is concatenating numbers, however, you could lose the ", TYPE" and "value('(./text())[1]','VARCHAR(MAX)' )"That code prevents special XML characters such as "<>&" from messing up your result set but slows the query performance. The OP is not returning any XML characters so the performance hit is not necessary.
Thanks Alan
July 21, 2017 at 5:28 am
Alan.B - Thursday, July 20, 2017 7:30 AMDesNorton - Thursday, July 20, 2017 5:29 AMinfo 58414 - Thursday, July 20, 2017 4:00 AMHi,
my Cross-Apply returns multiple Values. How can i bring these Values to 1 String (V1,V2,V3....) into my MainSelect?SELECT distinct
a.[NAME]
,c.OBJEKTID -- multiple Values-String
FROM [Devices] a
cross apply
(
Select objektid from [Devices] b
where a.OBJEKTID = b.OBJEKTID
) cData
Name OBJEKTID
d100 1001
d100 1002
d100 1003
d100 1004
d101 1011
d101 1012Result
d100 1001,1002,1003,1004
d101 1011,1012Regards
Nicole
:ermm:You could try something like this
SELECT
a.[NAME]
, OBJEKTID = LTRIM(RTRIM(
STUFF(
( SELECT ',' + CAST(b.OBJEKTID AS VARCHAR(10))
FROM [Devices] b
WHERE a.[NAME] = b.[NAME]
GROUP BY b.OBJEKTID
ORDER BY b.OBJEKTID
FOR XML PATH(''), TYPE).value('(./text())[1]','VARCHAR(MAX)'
), 1, 1, '')
))
FROM [Devices] a
GROUP BY a.[NAME]
ORDER BY a.[NAME]This is good. Since the OP is concatenating numbers, however, you could lose the ", TYPE" and "value('(./text())[1]','VARCHAR(MAX)' )"
That code prevents special XML characters such as "<>&" from messing up your result set but slows the query performance. The OP is not returning any XML characters so the performance hit is not necessary.
Heh... so does concatenation of values into a denormalized form. I have to wonder why this particular requirement is necessary.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply
This website stores cookies on your computer.
These cookies are used to improve your website experience and provide more personalized services to you, both on this website and through other media.
To find out more about the cookies we use, see our Privacy Policy