cancel
Showing results for 
Search instead for 
Did you mean: 

Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.

Reply
mcash
Helper I
Helper I

12 Month Averaging

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.

 

DateValue>>>12 Mo Avg A12 Mo Avg B 
1/1/202023.97    
2/1/202024.16    
3/1/202024.27    
4/1/202025.22    
5/1/202024.95    
6/1/202024.61    
7/1/202024.56    
8/1/202024.8    
9/1/202024.8    
10/1/202024.84    
11/1/202025.01    
12/1/202025.11    
1/1/202125.24    
2/1/202125.27    
3/1/202125.33    
4/1/202125.6    
5/1/202125.76    
6/1/202125.63    
7/1/202125.82    
8/1/202126.1    
9/1/202126.29    
10/1/202126.45    
11/1/202126.49    
12/1/202126.7    
1/1/202227.1    
2/1/202226.98    
3/1/202227.1 26.3427.10FILTERED RANGE
4/1/202227.36 26.4827.23 
5/1/202227.48 26.6327.31 
6/1/202227.35 26.7727.32 
7/1/202227.53 26.9127.36 
8/1/202227.6 27.0427.40 
9/1/202227.86 27.1727.47 
10/1/202228.09 27.3027.55 
11/1/202228.03 27.4327.60 
12/1/202228.15 27.5527.66 
1/1/202328.49 27.6727.73 
2/1/202328.42 27.7927.79 
3/1/202328.47 27.9027.90 
4/1/202328.86 28.0328.03 
5/1/202328.68 28.1328.13 
6/1/202328.64 28.2428.24 
7/1/202328.95 28.3528.35 
8/1/202328.84 28.4628.46 
1 ACCEPTED SOLUTION
v-shex-msft
Community Support
Community Support

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

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

1 REPLY 1
v-shex-msft
Community Support
Community Support

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

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

Helpful resources

Announcements
PBI November 2023 Update Carousel

Power BI Monthly Update - November 2023

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

Community News

Fabric Community News unified experience

Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.

Power BI Fabric Summit Carousel

The largest Power BI and Fabric virtual conference

130+ sessions, 130+ speakers, Product managers, MVPs, and experts. All about Power BI and Fabric. Attend online or watch the recordings.

Top Solution Authors
Top Kudoed Authors