Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Learn from the best! Meet the four finalists headed to the FINALS of the Power BI Dataviz World Championships! Register now
Hi there,
I've spent a long time searching the internet and have only found forumns on how to accomplish this via DAX, although I need a solution on Power Query as I intend to pivot the table depending on the custom column results.
I'm looking for how I can count a duplicate value and rank it as 1,2,3,... in the other column with Power Query
Eg.
| Name | new column |
| jame | 1 |
| jon | 1 |
| jame | 2 |
| jame | 3 |
| jon | 2 |
| jame | 4 |
| jon | 3 |
Any help would be much appreciated!
Thanks,
Ashling
Solved! Go to Solution.
Hello - you can accomplish this by: grouping > add an index for each row > add another index to the grouped table in each row > expand.
SCRIPT:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8srPyFOK1UFiBCcWJeJg+JQmV6IxMnNygKxYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Names = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Names", type text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Names"}, {{"Data", each _, type table [Names=nullable text, Index=number]}}),
#"Added Index" = Table.AddIndexColumn(#"Grouped Rows", "Index", 1, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "Subtable", each Table.AddIndexColumn ([Data], "Index2", 1, 1, Int64.Type )),
#"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Subtable", "Index"}),
#"Expanded Subtable" = Table.ExpandTableColumn(#"Removed Other Columns", "Subtable", {"Names", "Index2"}, {"Names", "Index2"})
in
#"Expanded Subtable"
NewStep=Table.FromRecords(List.Accumulate(Table.ToRecords(PreviousStepName),{{},[]},(x,y)=>let a=Record.TransformFields(x{1},{y[Name],each _+1??1}) in {x{0}&{y&[Count=Record.Field(a,y[Name])]}},a}){0})
Hello - you can accomplish this by: grouping > add an index for each row > add another index to the grouped table in each row > expand.
SCRIPT:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8srPyFOK1UFiBCcWJeJg+JQmV6IxMnNygKxYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Names = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Names", type text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Names"}, {{"Data", each _, type table [Names=nullable text, Index=number]}}),
#"Added Index" = Table.AddIndexColumn(#"Grouped Rows", "Index", 1, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "Subtable", each Table.AddIndexColumn ([Data], "Index2", 1, 1, Int64.Type )),
#"Removed Other Columns" = Table.SelectColumns(#"Added Custom",{"Subtable", "Index"}),
#"Expanded Subtable" = Table.ExpandTableColumn(#"Removed Other Columns", "Subtable", {"Names", "Index2"}, {"Names", "Index2"})
in
#"Expanded Subtable"
Share feedback directly with Fabric product managers, participate in targeted research studies and influence the Fabric roadmap.
Check out the February 2026 Power BI update to learn about new features.
| User | Count |
|---|---|
| 16 | |
| 12 | |
| 10 | |
| 7 | |
| 6 |