March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe 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
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:
Date | Month | Year | Country | Value |
01-06-2021 | June | 2021 | abc | 0 |
01-07-2021 | July | 2021 | abc | 12.87 |
01-05-2024 | May | 2024 | abc | 99.59 |
01-07-2024 | July | 2024 | abc | 111.45 |
01-10-2024 | October | 2024 | abc | 712.09 |
01-11-2024 | November | 2024 | abc | 126.14 |
01-01-2021 | January | 2021 | abc | 0 |
01-02-2021 | February | 2021 | abc | 0 |
01-03-2021 | March | 2021 | abc | 0 |
01-04-2021 | April | 2021 | abc | 0 |
01-05-2021 | May | 2021 | abc | 0 |
01-08-2021 | August | 2021 | abc | 0 |
01-09-2021 | September | 2021 | abc | 0 |
01-10-2021 | October | 2021 | abc | 0 |
01-11-2021 | November | 2021 | abc | 0 |
01-12-2021 | December | 2021 | abc | 0 |
01-01-2022 | January | 2022 | abc | 0 |
01-02-2022 | February | 2022 | abc | 0 |
01-03-2022 | March | 2022 | abc | 0 |
01-04-2022 | April | 2022 | abc | 0 |
01-05-2022 | May | 2022 | abc | 0 |
01-06-2022 | June | 2022 | abc | 0 |
01-07-2022 | July | 2022 | abc | 0 |
01-08-2022 | August | 2022 | abc | 0 |
01-09-2022 | September | 2022 | abc | 0 |
01-10-2022 | October | 2022 | abc | 0 |
01-11-2022 | November | 2022 | abc | 0 |
01-12-2022 | December | 2022 | abc | 0 |
01-01-2023 | January | 2023 | abc | 0 |
01-02-2023 | February | 2023 | abc | 0 |
01-03-2023 | March | 2023 | abc | 0 |
01-04-2023 | April | 2023 | abc | 0 |
01-05-2023 | May | 2023 | abc | 0 |
01-06-2023 | June | 2023 | abc | 0 |
01-07-2023 | July | 2023 | abc | 0 |
01-08-2023 | August | 2023 | abc | 0 |
01-09-2023 | September | 2023 | abc | 0 |
01-10-2023 | October | 2023 | abc | 0 |
01-11-2023 | November | 2023 | abc | 0 |
01-12-2023 | December | 2023 | abc | 0 |
01-01-2024 | January | 2024 | abc | 0 |
01-02-2024 | February | 2024 | abc | 0 |
01-03-2024 | March | 2024 | abc | 0 |
01-04-2024 | April | 2024 | abc | 0 |
01-06-2024 | June | 2024 | abc | 0 |
01-08-2024 | August | 2024 | abc | 0 |
01-09-2024 | September | 2024 | abc | 0 |
Im trying to calculate the rolling average for this by below dax:
Hi,
Do you want to show the 36 months rolling average for each month?
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.
The result of selecting a country is as follows.
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.
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.
Proud to be a Super User! | |
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
124 | |
82 | |
69 | |
53 | |
44 |
User | Count |
---|---|
202 | |
106 | |
100 | |
64 | |
56 |