Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register 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! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
146 | |
75 | |
64 | |
52 | |
47 |
User | Count |
---|---|
218 | |
88 | |
73 | |
64 | |
60 |