cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
tonyclifton
Helper II
Helper II

Calculate Average of current and previous two years

Hello community,


I have the following (simplified) data. I want to calculate the average of three years based on below table and show that value for the according year:

 

YearYearQuarterValue
20132013-0120
20132013-0240
20132013-0335
20132013-0410
20142014-0144
20142014-0216
20142014-0315
20142014-0410
20152015-0161
20152015-0235
20152015-0322
20152015-0420


And this would be the expected output for 2015:

YearValueAverage of 3 years
2013105
201485
2015138109

 

109 = (105 + 85 + 138) / 3

 

I hope you have an idea here because I am stuck.

Thank you.

1 ACCEPTED SOLUTION
Jihwan_Kim
Community Champion
Community Champion

Hi, @tonyclifton 

Please check the below picture and the sample pbix file's link down below.

 

Picture2.png

 

Value Total Measure =
SUM('Table'[Value])
 
Avg of 3 years =
VAR currentyear =
MAX ( 'Table'[Year] )
RETURN
IF (
currentyear - 1
< MINX ( ALL ( 'Table'[Year] ), 'Table'[Year] )
|| currentyear - 2
< MINX ( ALL ( 'Table'[Year] ), 'Table'[Year] ),
BLANK (),
AVERAGEX (
CALCULATETABLE (
VALUES ( 'Table'[Year] ),
FILTER (
ALL ( 'Table' ),
'Table'[Year] >= currentyear - 2
&& 'Table'[Year] <= currentyear
)
),
[Value Total Measure]
)
)
 
 
 

If this post helps, then please consider accept it as the solution to help other members find it faster, and give a big thumbs up.

Best regards, JiHwan Kim

Linkedin: https://www.linkedin.com/in/jihwankim1975/

Twitter: https://twitter.com/Jihwan_JHKIM

View solution in original post

3 REPLIES 3
Jihwan_Kim
Community Champion
Community Champion

Hi, @tonyclifton 

Please check the below picture and the sample pbix file's link down below.

 

Picture2.png

 

Value Total Measure =
SUM('Table'[Value])
 
Avg of 3 years =
VAR currentyear =
MAX ( 'Table'[Year] )
RETURN
IF (
currentyear - 1
< MINX ( ALL ( 'Table'[Year] ), 'Table'[Year] )
|| currentyear - 2
< MINX ( ALL ( 'Table'[Year] ), 'Table'[Year] ),
BLANK (),
AVERAGEX (
CALCULATETABLE (
VALUES ( 'Table'[Year] ),
FILTER (
ALL ( 'Table' ),
'Table'[Year] >= currentyear - 2
&& 'Table'[Year] <= currentyear
)
),
[Value Total Measure]
)
)
 
 
 

If this post helps, then please consider accept it as the solution to help other members find it faster, and give a big thumbs up.

Best regards, JiHwan Kim

Linkedin: https://www.linkedin.com/in/jihwankim1975/

Twitter: https://twitter.com/Jihwan_JHKIM

View solution in original post

Thank you very much @Jihwan_Kim . This works perfectly.

selimovd
Community Champion
Community Champion

Hey @tonyclifton ,

 

depending if you want to calculate whole years or from the max date or filter date you can use different approaches.

Check the function DATESINPERIOD function (DAX) - DAX | Microsoft Docs or PARALLELPERIOD function (DAX) - DAX | Microsoft Docs that can both extend the filter context of your date to 3 years.

 

Also be aware you need a proper date table in order to make the time intelligence functions work:

https://softcrylic.com/blogs/power-bi-for-beginners-how-to-create-a-date-table-in-power-bi/

 

If you need any help please let me know.
If I answered your question I would be happy if you could mark my post as a solution ✔️ and give it a thumbs up 👍
 
Best regards
Denis
 

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

2021 Release Wave 2 Plan

Power Platform release plan for the 2021 release wave 2 describes all new features releasing from October 2021 through March 2022.

July 2021 Update 768x460.png

Check it out!

Click here to read more about the July 2021 Updates

Power Query PA Forum 768x460.png

Check it out!

Did you know that you can visit the Power Query Forum in Power BI and now Power Apps

Top Solution Authors
Top Kudoed Authors