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 am struggling with a data exercise and could use some help.
I would like to return the value of column A, based on a grouped value of column B, where the value of column C is the highest.
Example:
Column B has the value 600001 in the first three rows, and the values 1, 2, 3 in column C.
The value I would like to sort out from column A is therefore 4223900.
I have tried conditioned formatting, returning max values, most anything shy of a manual sorting, but no luck.
Thanks!
Solved! Go to Solution.
Hi @Fda,
Without seeing your dataset, I'm not sure about the exact performance. If you want to try another way (and compare the two for your particular dataset), this can also be done outside of Power Query by creating a new column with DAX:
ColumnA_IfMax = IF ( CALCULATE ( MAX ( 'Table'[ColumnC] ), ALLEXCEPT ( 'Table', 'Table'[ColumnB] ) ) = 'Table'[ColumnC], 'Table'[ColumnA], BLANK() )
Hi @Fda,
Try this:
let Source = Excel.Workbook(File.Contents("C:\Users\rlosurdo\Desktop\GroupByColumn.xlsx"), null, true), Groups_Sheet = Source{[Item="Groups",Kind="Sheet"]}[Data], #"Promoted Headers" = Table.PromoteHeaders(Groups_Sheet, [PromoteAllScalars=true]), #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"ColumnA", Int64.Type}, {"ColumnB", Int64.Type}, {"ColumnC", Int64.Type}}), #"Added Custom" = Table.AddColumn(#"Changed Type", "MaxGroupValue", each let group = [ColumnB] in List.Max(Table.SelectRows(#"Changed Type", each [ColumnB] = group) [ColumnC])), #"Filtered Rows" = Table.SelectRows(#"Added Custom", each [MaxGroupValue] = [ColumnC]), #"Removed Other Columns" = Table.SelectColumns(#"Filtered Rows",{"ColumnA"}) in #"Removed Other Columns"
Thank you for taking your time, and it looks like its working!
Is it a heavy calculation for it to make? It's running pretty slow for me, and I've got a lot of rows left?
Hi @Fda,
Without seeing your dataset, I'm not sure about the exact performance. If you want to try another way (and compare the two for your particular dataset), this can also be done outside of Power Query by creating a new column with DAX:
ColumnA_IfMax = IF ( CALCULATE ( MAX ( 'Table'[ColumnC] ), ALLEXCEPT ( 'Table', 'Table'[ColumnB] ) ) = 'Table'[ColumnC], 'Table'[ColumnA], BLANK() )
You are a legend, that is exactly what I was looking for!
Thank you very much!
Glad to help!
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 |