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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
hungry_learner
Frequent Visitor

Rolling Average Issues

Hi All,

im new to Power BI and facing below issue.

im trying to calculate rolling average but somehow its not working with the measure i have created.

Sample data as follows:

 

DateMonthYearCountryValue
01-06-2021June2021abc0
01-07-2021July2021abc12.87
01-05-2024May2024abc99.59
01-07-2024July2024abc111.45
01-10-2024October2024abc712.09
01-11-2024November2024abc126.14
01-01-2021January2021abc0
01-02-2021February2021abc0
01-03-2021March2021abc0
01-04-2021April2021abc0
01-05-2021May2021abc0
01-08-2021August2021abc0
01-09-2021September2021abc0
01-10-2021October2021abc0
01-11-2021November2021abc0
01-12-2021December2021abc0
01-01-2022January2022abc0
01-02-2022February2022abc0
01-03-2022March2022abc0
01-04-2022April2022abc0
01-05-2022May2022abc0
01-06-2022June2022abc0
01-07-2022July2022abc0
01-08-2022August2022abc0
01-09-2022September2022abc0
01-10-2022October2022abc0
01-11-2022November2022abc0
01-12-2022December2022abc0
01-01-2023January2023abc0
01-02-2023February2023abc0
01-03-2023March2023abc0
01-04-2023April2023abc0
01-05-2023May2023abc0
01-06-2023June2023abc0
01-07-2023July2023abc0
01-08-2023August2023abc0
01-09-2023September2023abc0
01-10-2023October2023abc0
01-11-2023November2023abc0
01-12-2023December2023abc0
01-01-2024January2024abc0
01-02-2024February2024abc0
01-03-2024March2024abc0
01-04-2024April2024abc0
01-06-2024June2024abc0
01-08-2024August2024abc0
01-09-2024September2024abc0

 

Im trying to calculate the rolling average for this by below dax:

CALCULATE(
    AVERAGEX(
        FILTER(
            ALL('3-Year Calender'),
            '3-Year Calender'[Country] = SELECTEDVALUE('3-Year Calender'[Country]) &&
            '3-Year Calender'[Date] <= MAX('3-Year Calender'[Date]) &&
            '3-Year Calender'[Date] > EDATE(MAX('3-Year Calender'[Date]), -36)
        ),
        '3-Year Calender'[Value]
    )
)
 
I have 5 years of data but im limiting it to only current-36 months. But when i create calculated column/measure with this the values are correct. Even i put those two into table visualizatio it shows correct. But i want to show these into line chart. When i put that measure into line chart the chart shows blank and only works and shows lines when i select any country.


PS: when i use the calculated column in line chart it works but the value column is created using the multple columns and further it needs to be used in more calculations and when i try to do that it shows circular dependency error.
 
any help would be appreciated.
 
Thank you.
3 REPLIES 3
Ashish_Mathur
Super User
Super User

Hi,

Do you want to show the 36 months rolling average for each month?


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
v-denglli-msft
Community Support
Community Support

Thanks for the reply from rajendraongole1, please allow me to provide another insight.

Hi @hungry_learner ,

Please try the following measure.

Running average = 
VAR currentDate =
    MAX ( 'Table'[Date] )
RETURN
    CALCULATE (
        AVERAGE ( 'Table'[Value] ),
        'Table'[Date] <= currentDate
            && 'Table'[Date] > EDATE ( currentDate, -36 ),
        ALLSELECTED ( 'Table'[Country] )
    )

The result when no country is selected is as follows.

vdengllimsft_0-1735526280921.png

The result of selecting a country is as follows.

vdengllimsft_1-1735526338308.png


Please see the attached pbix for reference.

Best Regards,
Dengliang Li

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

rajendraongole1
Super User
Super User

Hi @hungry_learner - you're facing occurs because of how Power BI's line charts handle measures and filters. When you add a measure to a line chart without explicitly filtering by Country, the measure evaluates for all data points, and this can lead to blank results if no context is provided for the Country column.

 

Rolling Average =
VAR MaxDate = MAX('3-Year Calender'[Date])
VAR StartDate = EDATE(MaxDate, -36)
RETURN
CALCULATE(
AVERAGEX(
FILTER(
ALL('3-Year Calender'),
'3-Year Calender'[Country] = SELECTEDVALUE('3-Year Calender'[Country]) &&
'3-Year Calender'[Date] <= MaxDate &&
'3-Year Calender'[Date] > StartDate
),
'3-Year Calender'[Value]
)
)

 

You can adjust the measure to handle scenarios where no country is selected by providing a default behavior:

 

Rolling Average =
VAR MaxDate = MAX('3-Year Calender'[Date])
VAR StartDate = EDATE(MaxDate, -36)
VAR Result =
CALCULATE(
AVERAGEX(
FILTER(
ALL('3-Year Calender'),
'3-Year Calender'[Country] = SELECTEDVALUE('3-Year Calender'[Country]) &&
'3-Year Calender'[Date] <= MaxDate &&
'3-Year Calender'[Date] > StartDate
),
'3-Year Calender'[Value]
)
)
RETURN
IF(ISBLANK(SELECTEDVALUE('3-Year Calender'[Country])), BLANK(), Result)

 

Try the above both logics and let us know.





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!





Helpful resources

Announcements
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!

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.