Need Query for a problem

  • Hello Everybody,

    Consider the following table,

    create table SampleTable

    (Categoryvarchar(100), Organisams varchar(100) )

    Insert into Sampletable values ('Animals','Lion')

    Insert into Sampletable values ('Birds','Dove')

    Insert into Sampletable values ('Plants','Neem')

    Insert into Sampletable values ('Animals','Tiger')

    Insert into Sampletable values ('Birds','Eagle')

    Insert into Sampletable values ('Plants','Mango Tree')

    Insert into Sampletable values ('Animals','Cow')

    Insert into Sampletable values ('Birds','Parrot')

    Insert into Sampletable values ('Plants','Lime Tree')

    I Need following output,

    Category | Organisms

    -----------------------------

    Animals | Lion,Tiger,Cow

    Birds | Dove,Eagle,Parrot

    Plants | Neem,Mango Tree,Lime Tree

    Thanks in Advance

  • WITH CTE AS

    (

    SELECT DISTINCT

    Category

    FROM Sampletable

    )

    SELECT Category,

    Organisams = STUFF((

    SELECT ',' + Organisams

    FROM Sampletable

    WHERE Category = CTE.Category

    ORDER BY Organisams

    FOR XML PATH(''),

    TYPE).value('.','varchar(max)'),1,1,'')

    FROM CTE

    ORDER BY Category;

    There is an article related to this method below

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


    Kingston Dhasian

    How to post data/code on a forum to get the best help - Jeff Moden
    http://www.sqlservercentral.com/articles/Best+Practices/61537/

  • hats off to you...

    Thanks for the query..

    I have derived the output but that was quite complex

    create table SampleTable2

    (id int identity(1,1) ,Categoryvarchar(100), Organisams varchar(100) )

    insert into SampleTable2(Category)

    select distinct Category from sampletable

    DECLARE @listStr VARCHAR(MAX) ,@Category varchar(100),@i int

    set @i =1

    while (@i <= (select MAX(id)from SampleTable2 ))

    begin

    set @Category = (select category from SampleTable2 where id = @i)

    SELECT @listStr =''

    SELECT @listStr = COALESCE(@listStr,'') +','+Organisams

    FROM SampleTable where category=@category

    update SampleTable2 set Organisams = right(@listStr,LEN(@listStr)-1)

    where Category = @Category

    set @i = @i+1

    End

  • Works fine but im a newbie to SQL ...

    Please explain how it works....

  • vignesh.ms (6/16/2013)


    Works fine but im a newbie to SQL ...

    Please explain how it works....

    The explanation is present in the link I had provided earlier. I will add it once again for your reference.

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

    There is another article which contains a few more methods to achieve the same result

    You can check those as well and use whichever you prefer

    https://www.simple-talk.com/sql/t-sql-programming/concatenating-row-values-in-transact-sql/

    Edit:Added one more link to an article


    Kingston Dhasian

    How to post data/code on a forum to get the best help - Jeff Moden
    http://www.sqlservercentral.com/articles/Best+Practices/61537/

  • FOR XML is one of the best tools in MSSQL but I would regard it as something that only a power user should attempt as it's syntax is confusing.

    Basically it allows you to take an undefined number of records with a related key and convert them into a nested XML Group to pass on to other systems in a structured format (E.g. to be consumed by a webservice)

    <BOOKS>

    <BOOK>Wizard of Oz </BOOK>

    <BOOK>Frankensteins Monster</BOOK>

    <BOOK>Moby Dick</BOOK>

    </BOOKS>

    Building comma separated lists is the same concept except instead of <BOOK>...</BOOK> we will just use ' , '

    I would say don't worry about how it works, just play with the different parts to see what effect is has on the output. This will allow you to adapt the example to your real code.

  • aaron.reese (6/17/2013)


    I would say don't worry about how it works, just play with the different parts to see what effect is has on the output. This will allow you to adapt the example to your real code.

    I would have the exact opposite answer here. You are asking the OP to just blindly accept the code and move on. This is patently bad advice. It is the OP that has to support this code, they have to answer questions from others about how it works and what it does. An answer to those questions along the lines of "I don't know, I just got this code from some person on the Internet" is not a very good answer.

    To the OP, I would read through the articles that Kingston has provided and try to understand how this works. You don't need to know every single detail but you should understand what it is doing and why it works.

    _______________________________________________________________

    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/

Viewing 7 posts - 1 through 6 (of 6 total)

You must be logged in to reply to this topic. Login to reply