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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
Anonymous
Not applicable

Calculate the difference between yearly averages, for each individual user

The following is a sample user dataset where each user is assigned a rating at random times during the year (Some users are missing ratings for some of the years).

chris_eluva_0-1634581601943.png

I have a matrix visual with the average rating per user, per year. (See example below). So John Smith had 2 enteries for the year 2020 and the matrix has a single average value for that user, for each year that they have data for.

chris_eluva_2-1634581774271.png

What im trying to achieve is the Diff coloum (last coloum in 2nd visual), which is the difference between the 'latest average yearly rating' and 'earliest average yearly rating'. In Johns case this will be 1.225-0.936 (his value in 2021-2019). So "the earliest year" and "the latest year" with data could be different for each user. 

How can I calculate this coloum/ measure? 

Any help is much appreciated.

 

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

Hi @Anonymous ,

 

Create a measure.

Diff_M = var max_date =CALCULATE(MAX('Table'[Date ]),ALLEXCEPT('Table','Table'[ID]))

var min_date = CALCULATE(MIN('Table'[Date ]),ALLEXCEPT('Table','Table'[ID]))

var Max_value= MAXX(FILTER(ALL('Table'),'Table'[ID]=SELECTEDVALUE('Table'[ID])&&'Table'[Date ]=max_date),'Table'[Rating])

var Min_value=MINX(FILTER(ALL('Table'),'Table'[ID]=SELECTEDVALUE('Table'[ID])&&'Table'[Date ].[Date]=min_date),'Table'[Rating])

return

Max_value-Min_value

 

Or can create a column.

Diff = var max_date =CALCULATE(MAX('Table'[Date ].[Date]),FILTER('Table','Table'[ID]=EARLIER('Table'[ID])))

var min_date = CALCULATE(MIN('Table'[Date ]),FILTER('Table','Table'[ID]=EARLIER('Table'[ID])))

var Max_value= MAXX(FILTER(ALL('Table'),'Table'[ID]=EARLIER('Table'[ID])&&'Table'[Date ].[Date]=max_date),'Table'[Rating])

var Min_value=MINX(FILTER(ALL('Table'),'Table'[ID]=EARLIER('Table'[ID])&&'Table'[Date ].[Date]=min_date),'Table'[Rating])

return

Max_value-Min_value

44.PNG

Best Regards

Community Support Team _ polly

 

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

2 REPLIES 2
v-rongtiep-msft
Community Support
Community Support

Hi @Anonymous ,

 

Create a measure.

Diff_M = var max_date =CALCULATE(MAX('Table'[Date ]),ALLEXCEPT('Table','Table'[ID]))

var min_date = CALCULATE(MIN('Table'[Date ]),ALLEXCEPT('Table','Table'[ID]))

var Max_value= MAXX(FILTER(ALL('Table'),'Table'[ID]=SELECTEDVALUE('Table'[ID])&&'Table'[Date ]=max_date),'Table'[Rating])

var Min_value=MINX(FILTER(ALL('Table'),'Table'[ID]=SELECTEDVALUE('Table'[ID])&&'Table'[Date ].[Date]=min_date),'Table'[Rating])

return

Max_value-Min_value

 

Or can create a column.

Diff = var max_date =CALCULATE(MAX('Table'[Date ].[Date]),FILTER('Table','Table'[ID]=EARLIER('Table'[ID])))

var min_date = CALCULATE(MIN('Table'[Date ]),FILTER('Table','Table'[ID]=EARLIER('Table'[ID])))

var Max_value= MAXX(FILTER(ALL('Table'),'Table'[ID]=EARLIER('Table'[ID])&&'Table'[Date ].[Date]=max_date),'Table'[Rating])

var Min_value=MINX(FILTER(ALL('Table'),'Table'[ID]=EARLIER('Table'[ID])&&'Table'[Date ].[Date]=min_date),'Table'[Rating])

return

Max_value-Min_value

44.PNG

Best Regards

Community Support Team _ polly

 

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

collinq
Super User
Super User

Hi @Anonymous ,

 

To accomplish this, I think that easiest method would be for you to create a DAX formula that determines the earliest and latest year and then subtract those from each other.  If you need help with the exact formula, I would suggest that you make a feqeust in the DAX Commands forum for assistance on the syntax.




Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!
Private message me for consulting or training needs.




Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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
Top Kudoed Authors