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

Prepping for a Fabric certification exam? Join us for a live prep session with exam experts to learn how to pass the exam. Register now.

Reply
AA622
Helper II
Helper II

Rolling yearly Average

Hello

 

I am trying to calculate a rolling average. Its to calculate the yearly usage of a certain product over the last rolling 12 months and then from there I will calculate the daily average by working days (#260). 

 

I was using this formula but it doesnt match the actual yearly usage based on historical data.

UsageRollingYearly = CALCULATE(
    [Usage],
    DATESINPERIOD(
        'Calendar'[Date],
        MAX('Calendar'[Date]),
        -365,DAY))
 

I have another formula but I also cant seem to get it 100% right across all products

Usage12mo = CALCULATE (
[Usage],
FILTER ( ALL ( 'Calendar' ),
'Calendar'[Date] >= TODAY() - 365))
 
My question is which formula is more indicative of an accurate measure to calculate rolling 12 months usage?
 
Whatever number is calculated from either of these measures will be used to calculate daily average.
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @AA622 ,

Please update the formula of your measure [UsageRolling6mo] as below and check if it works or not...

UsageRolling6mo =
VAR __MaxDate =
    TODAY ()
VAR __EOM12 =
    EOMONTH ( __MaxDate, -12 )
VAR __MinDate =
    DATE ( YEAR ( __EOM12 ), MONTH ( __EOM12 ), DAY ( __MaxDate ) )
VAR __Table =
    FILTER (
        ALLSELECTED ( 'Calendar' ),
        'Calendar'[Date] <= __MaxDate
            && 'Calendar'[Date] >= __MinDate
    )
RETURN
    AVERAGEX ( __Table, [Usage] )

In addition, you can refer the following links to get the rolling average values:

Rolling Averages In Power BI

yingyinr_1-1665394209343.png

Rolling 12 Months Average in DAX

Best Regards

View solution in original post

3 REPLIES 3
Greg_Deckler
Super User
Super User

@AA622 Try:

 

Better RA =
    VAR __MaxDate = TODAY() 
    VAR __EOM12 = EOMONTH(__MaxDate,-12)
    VAR __MinDate = DATE(YEAR(__EOM12),MONTH(__EOM12),DAY(__MaxDate)
    VAR __Table = FILTER(ALLSELECTED('Table'),[Date] <= __MaxDate && [Date] >= __MinDate)
RETURN
    AVERAGEX(__Table,[Usage])

 

Both of the formulas you have currently are equally bad in my opinion because they do not account for leap years.



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Power BI Cookbook Third Edition (Color)

DAX is easy, CALCULATE makes DAX hard...

Better RA =
    VAR __MaxDate = TODAY() 
    VAR __EOM12 = EOMONTH(__MaxDate,-12)
    VAR __MinDate = DATE(YEAR(__EOM12),MONTH(__EOM12),DAY(__MaxDate)
    VAR __Table = FILTER(ALLSELECTED('Table'),[Date] <= __MaxDate && [Date] >= __MinDate)
RETURN
    AVERAGEX(__Table,[Usage])

 

HAving issues with the last VAR line. Line 5

 

Am I supposed to reference a table?

AA622_0-1665090504100.png

 

I tried referencing our Calendar Table. What would I put at the last line? I also seem to be having an issue with the mindate VAR in line 5

Anonymous
Not applicable

Hi @AA622 ,

Please update the formula of your measure [UsageRolling6mo] as below and check if it works or not...

UsageRolling6mo =
VAR __MaxDate =
    TODAY ()
VAR __EOM12 =
    EOMONTH ( __MaxDate, -12 )
VAR __MinDate =
    DATE ( YEAR ( __EOM12 ), MONTH ( __EOM12 ), DAY ( __MaxDate ) )
VAR __Table =
    FILTER (
        ALLSELECTED ( 'Calendar' ),
        'Calendar'[Date] <= __MaxDate
            && 'Calendar'[Date] >= __MinDate
    )
RETURN
    AVERAGEX ( __Table, [Usage] )

In addition, you can refer the following links to get the rolling average values:

Rolling Averages In Power BI

yingyinr_1-1665394209343.png

Rolling 12 Months Average in DAX

Best Regards

Helpful resources

Announcements
PBIApril_Carousel

Power BI Monthly Update - April 2025

Check out the April 2025 Power BI update to learn about new features.

Notebook Gallery Carousel1

NEW! Community Notebooks Gallery

Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.

April2025 Carousel

Fabric Community Update - April 2025

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