Results 1 to 4 of 4

Thread: Apply text to first row of every group of rows
Thanks Thanks: 0 Likes Likes: 0

  1. #1
    New Member
    Join Date
    Jul 2013
    Posts
    5
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Apply text to first row of every group of rows

    I am looking for a formula to apply text (in a new custom column) if it is the first row of a group of rows.

    Take a look at this example. I pull Column 1 and Column 2 from a SQL server, and I want to build the custom, third column, myself.


    Data:
    [Column 1] [Column 2] [Custom Column]
    A 10,000 First
    A 15,000 (blank)
    B 20,000 First
    C 5,000 First
    C 7,500 (blank)
    C 10,000 (blank)
    C 15,000 (blank)
    D 1,000 First
    D 10,000 (blank)
    E 100,000 First
    E 200,000 (blank
    E 300,000 (blank)

    One solution is to put the data in Excel and build an IF function (IF A2=A1;First;"") and Auto-Fill, but I don't want to switch back and forth between Power View and Excel tables (import en export) because I think that will cost performance.
    If it's possible in Power Query, that would be nice :D Or maybe in Power View.

  2. #2
    MrExcel MVP
    Moderator
    RoryA's Avatar
    Join Date
    May 2008
    Location
    UK
    Posts
    33,815
    Post Thanks / Like
    Mentioned
    48 Post(s)
    Tagged
    6 Thread(s)

    Default Re: Apply text to first row of every group of rows

    There are probably simpler ways, but here's one in PowerQuery. Hopefully the comments will allow you to adapt it to your real data:
    Code:
    let
        Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    
        /* this is the key field
        want a one column table converted to a list
        so we can return the first position of the key field later */
        GroupField = Table.ToList(Table.SelectColumns(Source,{"Field1"})),
    
        // add an index field to the source
        WithIndex = Table.AddIndexColumn(Source,"Index"),
    
        /* calculated column tests if Index number is the same as the first position
        of the key value in the list created earlier */
        FirstPos = Table.AddColumn(WithIndex, "Custom", each if List.PositionOf(GroupField, [Field1]) = [Index] then "First" else null),
    
        // remove index column
        FinalTable = Table.RemoveColumns(FirstPos, {"Index"})
    in
        FinalTable

  3. #3
    New Member
    Join Date
    Jul 2013
    Posts
    5
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Apply text to first row of every group of rows

    Quote Originally Posted by RoryA View Post
    There are probably simpler ways, but here's one in PowerQuery. Hopefully the comments will allow you to adapt it to your real data:
    Code:
    let
        Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    
        /* this is the key field
        want a one column table converted to a list
        so we can return the first position of the key field later */
        GroupField = Table.ToList(Table.SelectColumns(Source,{"Field1"})),
    
        // add an index field to the source
        WithIndex = Table.AddIndexColumn(Source,"Index"),
    
        /* calculated column tests if Index number is the same as the first position
        of the key value in the list created earlier */
        FirstPos = Table.AddColumn(WithIndex, "Custom", each if List.PositionOf(GroupField, [Field1]) = [Index] then "First" else null),
    
        // remove index column
        FinalTable = Table.RemoveColumns(FirstPos, {"Index"})
    in
        FinalTable
    Thanks for your effort! I am struggling to put in the query. It's a query with some filter steps and it seems that your source is from an Excel table. I have to adapt your formula to an existing query which is a bit hard for me. Is this still possible with your formula?

  4. #4
    MrExcel MVP
    Moderator
    RoryA's Avatar
    Join Date
    May 2008
    Location
    UK
    Posts
    33,815
    Post Thanks / Like
    Mentioned
    48 Post(s)
    Tagged
    6 Thread(s)

    Default Re: Apply text to first row of every group of rows

    Yes, you can just replace the Source line with whatever table your query currently returns as output. What does your M code look like now?

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •