Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Very specific query


Very specific query

Author
Message
branovuk
branovuk
Valued Member
Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)

Group: General Forum Members
Points: 68 Visits: 307
Hello All,
I have no idea at all how to do next:


Table:
ID_____Type_____ Term
1_____Subject_____ sky
2 _____Next _____ earth
2 _____Subject_____video
3_____Test _______black
4_____Subject _____white
4_____ Subject _____paper
4 _____Forms _____ red
4_____Subject _____stone
5_____Test ________head
6 ____Subject _____ leg
6 ____Subject _____ water

Query should check Subject in Type field and in a case of COUNT(ID) = 1 (and Type = Subject), field Result will be Term.
In a case of COUNT(ID) > 1 (and Type = Subject), field Result will be Term + ',' + Term + ',' ... ',' + Term
From table above:

ID_____Result
1_____ Sky
2_____ video
4_____ white, paper, stone
6_____ leg, water

Any idea?
Thanks,
Brano
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16671 Visits: 17030
Take a look at this article.

http://www.sqlservercentral.com/articles/comma+separated+list/71700/

_______________________________________________________________

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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
branovuk
branovuk
Valued Member
Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)

Group: General Forum Members
Points: 68 Visits: 307
Thanks Sean, will do,
Brano
branovuk
branovuk
Valued Member
Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)Valued Member (68 reputation)

Group: General Forum Members
Points: 68 Visits: 307
The way they explained it actually worked.
The only (kinda strange) behavior is if you try to save as a view:
It will give you some error; After, view result is good.
Opening again the same view: it is missing first line - but still working!
Thanks ...
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16671 Visits: 17030
This seems to work fine. There is no reason it should change just because it is in a view.


if OBJECT_ID('Something') is not null
drop table Something
GO
create table Something
(
ID int,
Type varchar(10),
Term varchar(10)
)

GO

insert Something
select 1, 'Subject', 'sky' union all
select 2, 'Next', 'earth' union all
select 2, 'Subject', 'video' union all
select 3, 'Test', 'black' union all
select 4, 'Subject', 'white' union all
select 4, 'Subject', 'paper' union all
select 4, 'Forms', 'red' union all
select 4, 'Subject', 'stone' union all
select 5, 'Test', 'head' union all
select 6, 'Subject', 'leg' union all
select 6, 'Subject', 'water'

GO

select * from Something

--here is the code not in a view
SELECT id,
Stuff((SELECT ', ' + Term
FROM Something s2
WHERE s1.id = s2.id
and s2.Type = 'Subject'
ORDER BY s2.Term
FOR XML PATH('')), 1, 1, '') as Result
FROM Something s1
where Type = 'Subject'
GROUP BY id

go

create view MyView as
SELECT id,
Stuff((SELECT ', ' + Term
FROM Something s2
WHERE s1.id = s2.id
and s2.Type = 'Subject'
ORDER BY s2.Term
FOR XML PATH('')), 1, 1, '') as Result
FROM Something s1
where Type = 'Subject'
GROUP BY id
go

select * from myview




_______________________________________________________________

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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
super48
super48
SSC Journeyman
SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)SSC Journeyman (83 reputation)

Group: General Forum Members
Points: 83 Visits: 500
how for xml path('') works here to get all values in single row?please explain
thanks and regards
sudarshan
kapil_kk
kapil_kk
SSCrazy
SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)

Group: General Forum Members
Points: 2437 Visits: 2763
Hi Sean,

I know to print comma seperated values using FOR XML.

But I was trying the same solution using COALESCE like this:

DECLARE @var varchar(max)
SELECT @var = coalesce(@var +',','') + term from Something where TYPE = 'subject'
select @var, ID from something
group by ID

its printing all term values in a single line... Can you please tell me what to modify in my script to get the same output as using FOR XML as you did

_______________________________________________________________
To get quick answer follow this link:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
kapil_kk
kapil_kk
SSCrazy
SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)SSCrazy (2.4K reputation)

Group: General Forum Members
Points: 2437 Visits: 2763
you can do the same thing as Sean did using SUBSTRING also:

SELECT id,
SUBSTRING((SELECT ', ' + Term
FROM Something s2
WHERE s1.id = s2.id
and s2.Type = 'Subject'
ORDER BY s2.Term
FOR XML PATH('')), 2, 1000) as Result
FROM Something s1
where Type = 'Subject'
GROUP BY id

_______________________________________________________________
To get quick answer follow this link:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16671 Visits: 17030
gurjer48 (6/26/2013)
how for xml path('') works here to get all values in single row?please explain
thanks and regards
sudarshan


Not quite sure what you are asking? Are you asking how does FOR XML work or are you asking how you get all values in a single row?

_______________________________________________________________

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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16671 Visits: 17030
kapil_kk (6/26/2013)
Hi Sean,

I know to print comma seperated values using FOR XML.

But I was trying the same solution using COALESCE like this:

DECLARE @var varchar(max)
SELECT @var = coalesce(@var +',','') + term from Something where TYPE = 'subject'
select @var, ID from something
group by ID

its printing all term values in a single line... Can you please tell me what to modify in my script to get the same output as using FOR XML as you did


No clue how you could do that Kapil. I think you would have to use a subquery to keep the ID in synch but then I don't have any idea how you would do it.

_______________________________________________________________

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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search