concatenate rows using for xml path and new line feed carriage

  • Since you just want a grid solution maybe something like this would work?

    ;with StateData as

    (

    select t1.*, ROW_NUMBER() over(partition by t1.STATE order by t1.city) as RowNum

    from #tempCityState t1

    join #tempCityState t2 on t1.STATE = t2.STATE and t1.City <> t2.City

    group by t1.STATE, t1.CITY

    )

    select case RowNum when 1 then STATE else '' end as STATE, City

    from StateData

    order by StateData.State, City

    I still say it would be better in the front end but this does what I think you are after.

    _______________________________________________________________

    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/

  • Sean Lange (3/22/2013)


    Since you just want a grid solution maybe something like this would work?

    ;with StateData as

    (

    select t1.*, ROW_NUMBER() over(partition by t1.STATE order by t1.city) as RowNum

    from #tempCityState t1

    join #tempCityState t2 on t1.STATE = t2.STATE and t1.City <> t2.City

    group by t1.STATE, t1.CITY

    )

    select case RowNum when 1 then STATE else '' end as STATE, City

    from StateData

    order by StateData.State, City

    I still say it would be better in the front end but this does what I think you are after.

    this gives a layout similar to what am looking however it does not group rows . the row concactenation has been lost: its not what am looking for . Tks anyway

  • julesbenone (3/22/2013)


    Sean Lange (3/22/2013)


    Since you just want a grid solution maybe something like this would work?

    ;with StateData as

    (

    select t1.*, ROW_NUMBER() over(partition by t1.STATE order by t1.city) as RowNum

    from #tempCityState t1

    join #tempCityState t2 on t1.STATE = t2.STATE and t1.City <> t2.City

    group by t1.STATE, t1.CITY

    )

    select case RowNum when 1 then STATE else '' end as STATE, City

    from StateData

    order by StateData.State, City

    I still say it would be better in the front end but this does what I think you are after.

    this gives a layout similar to what am looking however it does not group rows . the row concactenation has been lost: its not what am looking for . Tks anyway

    Then I would go back to my previous position that this belongs in the front end. I don't think you need to use Item Templates for this though. I tossed together a really quick page that does just what you are looking for.

    First your proc needs to be tweaked slightly.

    create proc RowsDisplayed as

    if object_id('tempdb..#tempCityState') is not null

    drop table #tempCityState

    Create TABLE #tempCityState (State Varchar(5), City Varchar(50))

    Insert Into #tempCityState

    Select 'CO', 'Denver' Union

    Select 'CO', 'Teluride' Union

    Select 'CO', 'Vail' Union

    Select 'CO', 'Aspen' Union

    Select 'CA', 'Los Anggeles' Union

    Select 'CA', 'Hanford' Union

    Select 'CA', 'Fremont' Union

    Select 'AK', 'Wynne' Union

    Select 'AK', 'Nashville'

    Select Distinct State, (Select Stuff((Select City + '

    '

    From #tempCityState

    Where State = t.State

    FOR Xml Path(''),TYPE).value('.','VARCHAR(1000)'),1,0,'')) AS Cities

    From #tempCityState t

    Now in your .net page you just need to add a grid. The HTML section looks like this.

    <asp:GridView ID="GridView1" runat="server" AutoGenerateColumns="False">

    <Columns>

    <asp:BoundField DataField="State" HeaderText="State">

    <ItemStyle VerticalAlign="Top" />

    </asp:BoundField>

    <asp:BoundField DataField="Cities" HeaderText="Cities" HtmlEncode="False" />

    </Columns>

    </asp:GridView>

    Notice that the Cities column has HtmlEncode = False. That means it will render any html as html instead of encoding it first.

    So to complete this I just created the following snippet in Page_Load:

    using (SqlConnection connection = new SqlConnection(ConfigurationManager.ConnectionStrings["ConnectionString"].ConnectionString))

    {

    string sql = "RowsDisplayed";

    SqlCommand command = new SqlCommand(sql, connection);

    command.CommandType = CommandType.StoredProcedure;

    connection.Open();

    SqlDataReader dr = command.ExecuteReader();

    GridView1.DataSource = dr;

    GridView1.DataBind();

    connection.Close();

    }

    The output looks like this:

    _______________________________________________________________

    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/

  • Sean Lange (3/22/2013)


    julesbenone (3/22/2013)


    Sean Lange (3/22/2013)


    Since you just want a grid solution maybe something like this would work?

    ;with StateData as

    (

    select t1.*, ROW_NUMBER() over(partition by t1.STATE order by t1.city) as RowNum

    from #tempCityState t1

    join #tempCityState t2 on t1.STATE = t2.STATE and t1.City <> t2.City

    group by t1.STATE, t1.CITY

    )

    select case RowNum when 1 then STATE else '' end as STATE, City

    from StateData

    order by StateData.State, City

    I still say it would be better in the front end but this does what I think you are after.

    this gives a layout similar to what am looking however it does not group rows . the row concactenation has been lost: its not what am looking for . Tks anyway

    Then I would go back to my previous position that this belongs in the front end. I don't think you need to use Item Templates for this though. I tossed together a really quick page that does just what you are looking for.

    First your proc needs to be tweaked slightly.

    create proc RowsDisplayed as

    if object_id('tempdb..#tempCityState') is not null

    drop table #tempCityState

    Create TABLE #tempCityState (State Varchar(5), City Varchar(50))

    Insert Into #tempCityState

    Select 'CO', 'Denver' Union

    Select 'CO', 'Teluride' Union

    Select 'CO', 'Vail' Union

    Select 'CO', 'Aspen' Union

    Select 'CA', 'Los Anggeles' Union

    Select 'CA', 'Hanford' Union

    Select 'CA', 'Fremont' Union

    Select 'AK', 'Wynne' Union

    Select 'AK', 'Nashville'

    Select Distinct State, (Select Stuff((Select City + '

    '

    From #tempCityState

    Where State = t.State

    FOR Xml Path(''),TYPE).value('.','VARCHAR(1000)'),1,0,'')) AS Cities

    From #tempCityState t

    Now in your .net page you just need to add a grid. The HTML section looks like this.

    <asp:GridView ID="GridView1" runat="server" AutoGenerateColumns="False">

    <Columns>

    <asp:BoundField DataField="State" HeaderText="State">

    <ItemStyle VerticalAlign="Top" />

    </asp:BoundField>

    <asp:BoundField DataField="Cities" HeaderText="Cities" HtmlEncode="False" />

    </Columns>

    </asp:GridView>

    Notice that the Cities column has HtmlEncode = False. That means it will render any html as html instead of encoding it first.

    So to complete this I just created the following snippet in Page_Load:

    using (SqlConnection connection = new SqlConnection(ConfigurationManager.ConnectionStrings["ConnectionString"].ConnectionString))

    {

    string sql = "RowsDisplayed";

    SqlCommand command = new SqlCommand(sql, connection);

    command.CommandType = CommandType.StoredProcedure;

    connection.Open();

    SqlDataReader dr = command.ExecuteReader();

    GridView1.DataSource = dr;

    GridView1.DataBind();

    connection.Close();

    }

    The output looks like this:

    Used the htmlencode = false but it didn't change nothing . please note i do already have a gridview.databind() code in my page load(). i was also unable to download the attachment: the link is taking me to the forum home page. In the latest tsql code that you provided i would appreciate if you can combine the first two lines togheter as not sure whether i got them copied correctly. have them as follow:

    Select Distinct State, (Select Stuff((Select City + ''

    Still believe i will have to use templatefield as a workaround even do i would prefer a boundfield which gives more flexibility in term of sorting and filtering

  • based on your various recommendations i finally found a good workable solution without having to compromise that much with my early tsql code in the views. i stayed with my first tqsl as follow:

    Stuff

    (

    (

    Select ',' + City As [text()]

    From #tempCityState

    Where State = t.State

    For Xml Path('')

    )

    , 1, 1, ''

    ) As Cities,

    Please note this is part of a view that is used in a stored procedure that feeds an asp.net gridview

    i made this adjustment in my stored procedures:

    Replace(ViewName.Cities, ',' , '

    ') AS Cities

    then after i added the HtmlEncode="False" property recommended by Sean in the BoundField.

    by using this solution i didn't have to review rows concactenation tsql code(s) i have in several views and as a result affect others sto proc and frontends that connect to my sql server database.

    To conclude i resolved my formatting problem by adding one additional property in my gridview boundfield and slightly adjusted a specific stored procedure that is only used by the asp.net application

    Thanks to all who have contributed in this thread ... i think the topic can be closed now .. happy week end

  • This code is a modification to the above post to have the cities adjusted under each other

    Create TABLE #tempCityState (State Varchar(5), City Varchar(50))

    Insert Into #tempCityState

    Select 'CO', 'Denver' Union

    Select 'CO', 'Teluride' Union

    Select 'CO', 'Vail' Union

    Select 'CO', 'Aspen' Union

    Select 'CA', 'Los Anggeles' Union

    Select 'CA', 'Hanford' Union

    Select 'CA', 'Fremont' Union

    Select 'AK', 'Wynne' Union

    Select 'AK', 'Nashville';

    with States as (

    select distinct

    State

    from

    #tempCityState

    )

    select

    State,

    stuff((select CHAR(9) + ' ' + City + char(13) + char(10)

    from #tempCityState tcs

    where tcs.State = States.State

    order by tcs.City

    for xml path(''),TYPE).value('.','varchar(max)'), 1, 3, '') as Cities

    from

    States;

    Drop table #tempCityState

Viewing 7 posts - 16 through 21 (of 21 total)

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