Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes! Register now.
I have the following data where I am trying to average the previous 12 months of Value and acheive the data in column "12 Mo Avg A" where the 12 month average is calculated regardless of the date slicer. All of the rolling average codes I've found on here returns column "12 Mo Avg B" where if I filter my date for a set period of time it will calculate the previous 12 months in each cell until the number of months within the filtered range is less than 12 and averages fewer and fewer months until it hits the minimum of the date range. Basically I need the calculation for measure Avg A to continue averaging back 12 months and only the visual to be filtered. In the table below the italicized numbers is an example of a filtered date range. I also have a Date table.
Date | Value | >>> | 12 Mo Avg A | 12 Mo Avg B | |
1/1/2020 | 23.97 | ||||
2/1/2020 | 24.16 | ||||
3/1/2020 | 24.27 | ||||
4/1/2020 | 25.22 | ||||
5/1/2020 | 24.95 | ||||
6/1/2020 | 24.61 | ||||
7/1/2020 | 24.56 | ||||
8/1/2020 | 24.8 | ||||
9/1/2020 | 24.8 | ||||
10/1/2020 | 24.84 | ||||
11/1/2020 | 25.01 | ||||
12/1/2020 | 25.11 | ||||
1/1/2021 | 25.24 | ||||
2/1/2021 | 25.27 | ||||
3/1/2021 | 25.33 | ||||
4/1/2021 | 25.6 | ||||
5/1/2021 | 25.76 | ||||
6/1/2021 | 25.63 | ||||
7/1/2021 | 25.82 | ||||
8/1/2021 | 26.1 | ||||
9/1/2021 | 26.29 | ||||
10/1/2021 | 26.45 | ||||
11/1/2021 | 26.49 | ||||
12/1/2021 | 26.7 | ||||
1/1/2022 | 27.1 | ||||
2/1/2022 | 26.98 | ||||
3/1/2022 | 27.1 | 26.34 | 27.10 | FILTERED RANGE | |
4/1/2022 | 27.36 | 26.48 | 27.23 | ||
5/1/2022 | 27.48 | 26.63 | 27.31 | ||
6/1/2022 | 27.35 | 26.77 | 27.32 | ||
7/1/2022 | 27.53 | 26.91 | 27.36 | ||
8/1/2022 | 27.6 | 27.04 | 27.40 | ||
9/1/2022 | 27.86 | 27.17 | 27.47 | ||
10/1/2022 | 28.09 | 27.30 | 27.55 | ||
11/1/2022 | 28.03 | 27.43 | 27.60 | ||
12/1/2022 | 28.15 | 27.55 | 27.66 | ||
1/1/2023 | 28.49 | 27.67 | 27.73 | ||
2/1/2023 | 28.42 | 27.79 | 27.79 | ||
3/1/2023 | 28.47 | 27.90 | 27.90 | ||
4/1/2023 | 28.86 | 28.03 | 28.03 | ||
5/1/2023 | 28.68 | 28.13 | 28.13 | ||
6/1/2023 | 28.64 | 28.24 | 28.24 | ||
7/1/2023 | 28.95 | 28.35 | 28.35 | ||
8/1/2023 | 28.84 | 28.46 | 28.46 |
Solved! Go to Solution.
HI @mcash,
I think you may need to create unconnected table as source for date filter. Then you can write measure expression to check the current date range and show the result of rolling 12 month records.
formula =
VAR SelectRange =
VALUE ( NewTable[Date] )
VAR currDate =
MAX ( Table[Date] )
VAR rollingAVG =
CALCULATE (
AVERAGE ( Table[Value] ),
FILTER (
ALLSELECTED ( Table ),
[Date]
>= DATE ( YEAR ( currdate ) - 1, MONTH ( currDate ), DAY ( currDate ) )
&& [Date] <= currDate
)
)
RETURN
IF ( currDate IN SelectRange, rollingAVG )
Regards,
Xiaoxin Sheng
HI @mcash,
I think you may need to create unconnected table as source for date filter. Then you can write measure expression to check the current date range and show the result of rolling 12 month records.
formula =
VAR SelectRange =
VALUE ( NewTable[Date] )
VAR currDate =
MAX ( Table[Date] )
VAR rollingAVG =
CALCULATE (
AVERAGE ( Table[Value] ),
FILTER (
ALLSELECTED ( Table ),
[Date]
>= DATE ( YEAR ( currdate ) - 1, MONTH ( currDate ), DAY ( currDate ) )
&& [Date] <= currDate
)
)
RETURN
IF ( currDate IN SelectRange, rollingAVG )
Regards,
Xiaoxin Sheng