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!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hi all,
I am quite new to the Power Query Editor. I've been trying to add an order/count based on an distinct ID like the example below.
ID | ORDER |
1 | 1 |
1 | 2 |
1 | 3 |
2 | 1 |
2 | 2 |
3 | 1 |
3 | 2 |
3 | 3 |
3 | 4 |
So I'd like to create column 2 (ORDER). I've been trying myself, but I am still quite unfamaliar with this language and having a bit of a hard time to solve this one. Also I was unable to find it in other topics. In Excel I was able to achieve it via the countif statement, but my dataset is too large to handle it via excel.
Solved! Go to Solution.
See if this works @chris12345
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlSK1UEljZBIY2xkLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t]),
#"Grouped Rows" =
Table.Group(
Source,
{"ID"},
{
{"Order", each Table.AddIndexColumn(_, "Order", 1, 1, Int64.Type)}
}
),
#"Expanded Order" = Table.ExpandTableColumn(#"Grouped Rows", "Order", {"Order"}, {"Order"}),
#"Changed Type" = Table.TransformColumnTypes(#"Expanded Order",{{"Order", Int64.Type}})
in
#"Changed Type"
It returns this.
How to use M code provided in a blank query:
1) In Power Query, select New Source, then Blank Query
2) On the Home ribbon, select "Advanced Editor" button
3) Remove everything you see, then paste the M code I've given you in that box.
4) Press Done
5) See this article if you need help using this M code in your model.
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI ReportingHi, @chris12345
Based on your description, I created data to reproduce your sceanrio. The pbix file is attached in the end.
Table:
You may apply the following transformations in Power Query. Here are the m codes in 'Advanced Editor'.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlSK1UEljZBIY2xkLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}}),
Custom1 = Table.Group(#"Changed Type",{"ID"},{"Order",(x)=> List.Generate(
()=>1,
each _<=Table.RowCount(x),
each _+1
)
}
),
#"Expanded Order" = Table.ExpandListColumn(Custom1, "Order"),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded Order",{{"Order", Int64.Type}})
in
#"Changed Type1"
Result:
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @chris12345
Based on your description, I created data to reproduce your sceanrio. The pbix file is attached in the end.
Table:
You may apply the following transformations in Power Query. Here are the m codes in 'Advanced Editor'.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlSK1UEljZBIY2xkLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}}),
Custom1 = Table.Group(#"Changed Type",{"ID"},{"Order",(x)=> List.Generate(
()=>1,
each _<=Table.RowCount(x),
each _+1
)
}
),
#"Expanded Order" = Table.ExpandListColumn(Custom1, "Order"),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded Order",{{"Order", Int64.Type}})
in
#"Changed Type1"
Result:
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
See if this works @chris12345
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlSK1UEljZBIY2xkLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t]),
#"Grouped Rows" =
Table.Group(
Source,
{"ID"},
{
{"Order", each Table.AddIndexColumn(_, "Order", 1, 1, Int64.Type)}
}
),
#"Expanded Order" = Table.ExpandTableColumn(#"Grouped Rows", "Order", {"Order"}, {"Order"}),
#"Changed Type" = Table.TransformColumnTypes(#"Expanded Order",{{"Order", Int64.Type}})
in
#"Changed Type"
It returns this.
How to use M code provided in a blank query:
1) In Power Query, select New Source, then Blank Query
2) On the Home ribbon, select "Advanced Editor" button
3) Remove everything you see, then paste the M code I've given you in that box.
4) Press Done
5) See this article if you need help using this M code in your model.
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI ReportingThe Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 19 | |
| 10 | |
| 9 | |
| 7 | |
| 6 |