cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
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
Microsoft
Microsoft

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
Microsoft
Microsoft

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

Super User IV
Super User IV

@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])))



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

@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
secondImage

Happy New Year from Power BI

This is a must watch for a message from Power BI!

December Update

Check it Out!

Click here to read more about the December 2020 Updates!

Community Blog

Check it Out!

Click here to read the latest blog and learn more about contributing to the Power BI blog!

Get Ready for Power BI Dev Camp

Get Ready for Power BI Dev Camp

Mark your calendars and join us for our next Power BI Dev Camp!.

Top Solution Authors
Top Kudoed Authors