March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hi,
I want to filter a table so that I keep those rows that have the maximum value in a column. For example, I have:
Name | Col 2 | Col 3 | Col 4 | Revision no |
A | .. | .. | .. | 0 |
A | .. | .. | .. | 1 |
A | .. | .. | .. | 2 |
B | .. | .. | .. | 0 |
B | .. | .. | .. | 1 |
C | .. | .. | .. | 0 |
D | .. | .. | .. | 0 |
After filtering; I want:
Name | Col 2 | Col 3 | Col 4 | Revision no |
A | .. | .. | .. | 2 |
B | .. | .. | .. | 1 |
C | .. | .. | .. | 0 |
D | .. | .. | .. | 0 |
Is there a simple way of avhieving this result?
Solved! Go to Solution.
Hi, @bkermen
Try this:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTIEYiMgNgZiA6VYHYgoTMQErAImChMxBasAiTphNcEJqwnOWNW6YIrGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, #"Col 2" = _t, #"Col 3" = _t, #"Col 4" = _t, #"Revision no" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Col 2", type text}, {"Col 3", type text}, {"Col 4", type text}, {"Revision no", Int64.Type}}),
T2=Table.Group(#"Changed Type", {"Name"}, {{"max", each List.Max([Revision no]), type nullable number}}),
#"Merged Queries" = Table.NestedJoin(#"Changed Type", {"Name", "Revision no"}, T2, {"Name", "max"}, "Table (2)", JoinKind.LeftOuter),
#"Expanded Table (2)" = Table.ExpandTableColumn(#"Merged Queries", "Table (2)", {"max"}, {"Table (2).max"}),
#"Filtered Rows" = Table.SelectRows(#"Expanded Table (2)", each ([#"Table (2).max"] <> null)),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Table (2).max"})
in
#"Removed Columns"
Result:
Please refer to the attachment below for details. Hope this helps.
Best Regards,
Community Support Team _ Zeon Zheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @bkermen
Try this:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTIEYiMgNgZiA6VYHYgoTMQErAImChMxBasAiTphNcEJqwnOWNW6YIrGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, #"Col 2" = _t, #"Col 3" = _t, #"Col 4" = _t, #"Revision no" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Col 2", type text}, {"Col 3", type text}, {"Col 4", type text}, {"Revision no", Int64.Type}}),
T2=Table.Group(#"Changed Type", {"Name"}, {{"max", each List.Max([Revision no]), type nullable number}}),
#"Merged Queries" = Table.NestedJoin(#"Changed Type", {"Name", "Revision no"}, T2, {"Name", "max"}, "Table (2)", JoinKind.LeftOuter),
#"Expanded Table (2)" = Table.ExpandTableColumn(#"Merged Queries", "Table (2)", {"max"}, {"Table (2).max"}),
#"Filtered Rows" = Table.SelectRows(#"Expanded Table (2)", each ([#"Table (2).max"] <> null)),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Table (2).max"})
in
#"Removed Columns"
Result:
Please refer to the attachment below for details. Hope this helps.
Best Regards,
Community Support Team _ Zeon Zheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@smpa01 This seems to work only if the values in the other columns (Col 2-4) are identical. What I actually want to do is to filter the data in Power Query Editor so that only the filtered rows are in the data model.
@bkermen you can use a measure like this
Measure = CALCULATE(MAX('Table'[Revision no]),ALLEXCEPT('Table','Table'[Name]))
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
129 | |
90 | |
75 | |
58 | |
53 |
User | Count |
---|---|
200 | |
104 | |
101 | |
67 | |
55 |