June 20, 2013 at 10:07 am
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
June 20, 2013 at 10:11 am
Take a look at this article.
http://www.sqlservercentral.com/articles/comma+separated+list/71700/[/url]
_______________________________________________________________
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/
June 20, 2013 at 1:52 pm
Thanks Sean, will do,
Brano
June 21, 2013 at 1:38 pm
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 ...
June 21, 2013 at 1:51 pm
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 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/
June 26, 2013 at 12:11 am
how for xml path('') works here to get all values in single row?please explain
thanks and regards
sudarshan
June 26, 2013 at 1:24 am
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/
June 26, 2013 at 1:26 am
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/
June 26, 2013 at 8:54 am
gurjer48 (6/26/2013)
how for xml path('') works here to get all values in single row?please explainthanks 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 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/
June 26, 2013 at 8:58 am
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 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/
June 26, 2013 at 9:01 am
kapil_kk (6/26/2013)
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
The problem here is that you have to choose an arbitrary length. In your case it was 1000 which is plenty to cover the sample data. The issue can be demonstrated by changing the length to something shorter than the output you can see what happens.
Let's change the length to 10 instead 1000.
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, 10) AS Result
FROM Something s1
WHERE Type = 'Subject'
GROUP BY id
_______________________________________________________________
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/
June 26, 2013 at 11:25 pm
Sean Lange (6/26/2013)
kapil_kk (6/26/2013)
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
The problem here is that you have to choose an arbitrary length. In your case it was 1000 which is plenty to cover the sample data. The issue can be demonstrated by changing the length to something shorter than the output you can see what happens.
Let's change the length to 10 instead 1000.
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, 10) AS Result
FROM Something s1
WHERE Type = 'Subject'
GROUP BY id
Yes, Sean changing length can arise problem...thanks for correcting that
_______________________________________________________________
To get quick answer follow this link:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply