Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Mainer04401
Helper III
Helper III

Max in calculated column excluding current row

I created a column with the following expression to calculate the maximum sales of an account for a product in a zip code:
 
MaxSales =
calculate(max(Table[Sales]),allexcept(Table,Table[ZipCode],Table[Product]))
 
It works, but now I want to exclude the current row from the maximum calculation.  In other words, if the current account has the maximum sales, then show the second highest account's sales.  See the example below:
 
AccountNumberZipCodeProductSalesMaxSales
10104401Chairs7501,000
10204401Chairs1,000750
10304401Chairs3001,000
10404401Chairs4001,000

 

Is this possible?  I know I can do this as a measure but I'm trying to make it a calculated column to see if this improves the speed by not doing the maximum calculation on the fly.  

1 ACCEPTED SOLUTION
v-yangliu-msft
Community Support
Community Support

Hi  @Mainer04401 ,

Here are the steps you can follow:

1. Create calculated column.

Column =
var _1 =CALCULATE(MAX('Table'[Sales]),FILTER('Table','Table'[Sales]=MAX('Table'[Sales])))
var _2 =CALCULATE(SUM('Table'[Sales]),FILTER('Table',RANKX('Table','Table'[Sales])=2))
return IF('Table'[Sales]=MAX('Table'[Sales]),_2,_1)

2. Result.

v-yangliu-msft_0-1607071556404.png

You can downloaded PBIX file from here.

 

Best Regards,

Liu Yang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-yangliu-msft
Community Support
Community Support

Hi  @Mainer04401 ,

Here are the steps you can follow:

1. Create calculated column.

Column =
var _1 =CALCULATE(MAX('Table'[Sales]),FILTER('Table','Table'[Sales]=MAX('Table'[Sales])))
var _2 =CALCULATE(SUM('Table'[Sales]),FILTER('Table',RANKX('Table','Table'[Sales])=2))
return IF('Table'[Sales]=MAX('Table'[Sales]),_2,_1)

2. Result.

v-yangliu-msft_0-1607071556404.png

You can downloaded PBIX file from here.

 

Best Regards,

Liu Yang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

amitchandak
Super User
Super User

@Mainer04401 , Try a measure like

calculate(Max(Table[Sales]), filter(allselected(Table[AccountNumber]) ,Table[AccountNumber] <> max(Table[AccountNumber])))

 

or

calculate(Max(Table[Sales]), filter(allselected(Table) ,Table[AccountNumber] <> max(Table[AccountNumber])))

@amitchandak Thanks, I've gotten this to work as a measure but I'm trying to make a calculated column so that the calculation occurs during data refresh and not on the fly.  Can the current row's value be excluded from the maximum calculation when doing so in a calculated column?

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors