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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
sonya7
Helper III
Helper III

How to get last 12 month moving average?

I have Amount data based on 

Startdate date. How can I write the 12-month average?

 

 

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

Hi  @sonya7 ,

I created some data:

vyangliumsft_0-1669273979904.png

Here are the steps you can follow:

1. Create measure.

Date_Measure =
var _date=DATE(YEAR(MAX('Table'[Date]))-1,MONTH(MAX('Table'[Date])),DAY(MAX('Table'[Date])))
return
AVERAGEX(FILTER(ALL('Table'),
'Table'[Date]>=_date&&'Table'[Date]<=MAX('Table'[Date])),[Amount])
Month_Measure =
var _dateEND=
EOMONTH(MAX('Table'[Date]),0)
var _dateEND2=
EOMONTH(MAX('Table'[Date]),-12)
var _datestart=
DATE(
    YEAR(_dateEND2),MONTH(_dateEND2),1)
return
AVERAGEX(FILTER(ALL('Table'),'Table'[Date]>=_datestart&&'Table'[Date]<=_dateEND),[Amount])

2. Result:

vyangliumsft_1-1669273979910.png

 

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  @sonya7 ,

I created some data:

vyangliumsft_0-1669273979904.png

Here are the steps you can follow:

1. Create measure.

Date_Measure =
var _date=DATE(YEAR(MAX('Table'[Date]))-1,MONTH(MAX('Table'[Date])),DAY(MAX('Table'[Date])))
return
AVERAGEX(FILTER(ALL('Table'),
'Table'[Date]>=_date&&'Table'[Date]<=MAX('Table'[Date])),[Amount])
Month_Measure =
var _dateEND=
EOMONTH(MAX('Table'[Date]),0)
var _dateEND2=
EOMONTH(MAX('Table'[Date]),-12)
var _datestart=
DATE(
    YEAR(_dateEND2),MONTH(_dateEND2),1)
return
AVERAGEX(FILTER(ALL('Table'),'Table'[Date]>=_datestart&&'Table'[Date]<=_dateEND),[Amount])

2. Result:

vyangliumsft_1-1669273979910.png

 

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

@sonya7 , Try a measure like

 

12 Month Avg = CALCULATE(AverageX(Values('Date'[MONTH Year]),calculate(Sum('Table'[Value)))
,DATESINPERIOD('Date'[Date ],MAX('Date'[Date ]),-12,MONTH))

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

It is correct in total but returns incorrect results on a monthly basis(brings itself) .Can you be more specific for the date field?

sonya7_0-1669188979501.png

 

 

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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