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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
srk_powerbi
Helper II
Helper II

Calculation help needed.. avg of all other rows except current row

hi,

i have  a table below. I want to calculate avg of ProductsPurchased of all other rows except current row. And there is filter Year.

ex:   for first row in below table,  'Avg of all others'  should be the below value ( avg of 200+25+100  for year 2016). 

Please help.

Year   Customer   ProductsPurchased   Avg of all others

2016   A              225                               108.3

Year  CustomerProductPurchased

2016A225
2016B200
2016C25
2016D100
2015A158
2015B150
2015C30
2015D90
1 ACCEPTED SOLUTION

Hi @srk_powerbi ,

 

Create a measure like this:

Measure = var cur_cus = MAX('Table'[Customer])
return
CALCULATE(AVERAGE('Table'[sales]),FILTER(ALLEXCEPT('Table','Table'[Year]),'Table'[Customer]<>cur_cus))

V-lianl-msft_0-1608188673552.png

 

 

Best Regards,
Liang
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
srk_powerbi
Helper II
Helper II

@Greg_Deckler  thanks.  the calculated column you provided above gives me the sum. Now  how can i calculate avg?

Also, can i do the same by creating a Measure inst?ead  of calculated column?

Hi @srk_powerbi ,

 

Create a measure like this:

Measure = var cur_cus = MAX('Table'[Customer])
return
CALCULATE(AVERAGE('Table'[sales]),FILTER(ALLEXCEPT('Table','Table'[Year]),'Table'[Customer]<>cur_cus))

V-lianl-msft_0-1608188673552.png

 

 

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

 

Greg_Deckler
Super User
Super User

@srk_powerbi If you add an ID column in Power Query then this should be easier and more certain. Otherwise you can use variables or EARLIER to identify rows other than the current row. See my article on Mean Time Between Failure (MTBF) which uses EARLIER: http://community.powerbi.com/t5/Community-Blog/Mean-Time-Between-Failure-MTBF-and-Power-BI/ba-p/3395....
The basic pattern is:
Column = 
  VAR __Current = [Value]
  VAR __PreviousDate = MAXX(FILTER('Table','Table'[Date] < EARLIER('Table'[Date])),[Date])

  VAR __Previous = MAXX(FILTER('Table',[Date]=__PreviousDate),[Value])
RETURN
  __Current - __Previous

 

In your case, you could do something like: 

 

Column = SUMX(FILTER('Table',[Year]=EARLIER([Year]) && [Customer]<>EARLIER([Customer])),[ProductPurchased)


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors