Apply text to first row of every group of rows

farris

New Member
Joined
Jul 18, 2013
Messages
5
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.
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
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
 
Upvote 0
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?
 
Upvote 0
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?
 
Upvote 0

Forum statistics

Threads
1,213,514
Messages
6,114,078
Members
448,547
Latest member
arndtea

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top