Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet 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
I have Amount data based on
Startdate date. How can I write the 12-month average?
Solved! Go to Solution.
Hi @sonya7 ,
I created some data:
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:
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
Hi @sonya7 ,
I created some data:
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:
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
@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))
It is correct in total but returns incorrect results on a monthly basis(brings itself) .Can you be more specific for the date field?
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
90 | |
86 | |
83 | |
64 | |
49 |
User | Count |
---|---|
127 | |
108 | |
87 | |
70 | |
66 |