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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
kotarosai
Helper II
Helper II

Rolling Average: Stop Date

I feel this is close, but please find the formula for a 20 day rolling average below. The measure actually works great and is accurate, except for the fact that when plotted on a line chart, it goes past beyond the [Latest Date Loaded] which is also posted below. Any idea on why it does not cut off on the [Latest Date Loaded]? The 'Sales Result'[CAS_Bonus_date__c] is related to the date table field of 'Date Table'[Date] as well. I appreciate your feedback, thanks!

 

 

Total Sales = SUM('Sales Result'[Net_Sales_Units__c])

 

 

 

Latest Date Loaded = VAR X = SUMMARIZE(ALL('Sales Result'),'Sales Result'[Account],"M",CALCULATE(MAX('Sales Result'[CAS_Bonus_Date__c]),'Sales Result'[RecordTypeId]="0126g000000O4VdAAK",'Sales Result'[Region__c]<>"Specialty Pharmacy"))
RETURN MAXX(x,[M])

 

 

 

4 Week Moving Average Chart = 
CALCULATE(
    [Total Sales],
    DATESINPERIOD('Date Table'[Date],LASTDATE('Date Table'[Date]),-20,DAY),
    FILTER(ALLSELECTED('Date Table'),'Date Table'[Working Day] = 1 &&
    'Date Table'[Date] <= [Latest Date Loaded]))
    /
CALCULATE(
    DISTINCTCOUNT('Date Table'[Date]),
    DATESINPERIOD('Date Table'[Date],LASTDATE('Date Table'[Date]),-20, DAY),
    FILTER(ALLSELECTED('Date Table'),'Date Table'[Working Day] = 1 &&
    'Date Table'[Date] <= [Latest Date Loaded]))

 

 

 image.png

1 ACCEPTED SOLUTION
v-lili6-msft
Community Support
Community Support

hi @kotarosai 

You need to create a IF conditional in the measure as below:

4 Week Moving Average Chart =
IF(
MAX('Sales Result'[CAS_Bonus_date__c])<=[Latest Date Loaded]
&&MAX('Sales Result'[CAS_Bonus_date__c])<>BLANK(),
CALCULATE(
[Total Sales],
DATESINPERIOD('Date Table'[Date],LASTDATE('Date Table'[Date]),-20,DAY),
FILTER(ALLSELECTED('Date Table'),'Date Table'[Working Day] = 1 &&
'Date Table'[Date] <= [Latest Date Loaded]))
/
CALCULATE(
DISTINCTCOUNT('Date Table'[Date]),
DATESINPERIOD('Date Table'[Date],LASTDATE('Date Table'[Date]),-20, DAY),
FILTER(ALLSELECTED('Date Table'),'Date Table'[Working Day] = 1 &&
'Date Table'[Date] <= [Latest Date Loaded])))

 

or

 

4 Week Moving Average Chart =
IF(
MAX('Sales Result'[CAS_Bonus_date__c])<=[Latest Date Loaded]
&&MAX('Sales Result'[CAS_Bonus_date__c])<>BLANK(),
CALCULATE(
[Total Sales],
DATESINPERIOD('Date Table'[Date],LASTDATE('Date Table'[Date]),-20,DAY),
FILTER(ALLSELECTED('Date Table'),'Date Table'[Working Day] = 1 &&
'Date Table'[Date] <= [Latest Date Loaded]))
/
CALCULATE(
DISTINCTCOUNT('Date Table'[Date]),
DATESINPERIOD('Date Table'[Date],LASTDATE('Date Table'[Date]),-20, DAY),
FILTER(ALLSELECTED('Date Table'),'Date Table'[Working Day] = 1 &&
'Date Table'[Date] <= [Latest Date Loaded])))
 
 
Regards,
Lin
Community Support Team _ Lin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-lili6-msft
Community Support
Community Support

hi @kotarosai 

You need to create a IF conditional in the measure as below:

4 Week Moving Average Chart =
IF(
MAX('Sales Result'[CAS_Bonus_date__c])<=[Latest Date Loaded]
&&MAX('Sales Result'[CAS_Bonus_date__c])<>BLANK(),
CALCULATE(
[Total Sales],
DATESINPERIOD('Date Table'[Date],LASTDATE('Date Table'[Date]),-20,DAY),
FILTER(ALLSELECTED('Date Table'),'Date Table'[Working Day] = 1 &&
'Date Table'[Date] <= [Latest Date Loaded]))
/
CALCULATE(
DISTINCTCOUNT('Date Table'[Date]),
DATESINPERIOD('Date Table'[Date],LASTDATE('Date Table'[Date]),-20, DAY),
FILTER(ALLSELECTED('Date Table'),'Date Table'[Working Day] = 1 &&
'Date Table'[Date] <= [Latest Date Loaded])))

 

or

 

4 Week Moving Average Chart =
IF(
MAX('Sales Result'[CAS_Bonus_date__c])<=[Latest Date Loaded]
&&MAX('Sales Result'[CAS_Bonus_date__c])<>BLANK(),
CALCULATE(
[Total Sales],
DATESINPERIOD('Date Table'[Date],LASTDATE('Date Table'[Date]),-20,DAY),
FILTER(ALLSELECTED('Date Table'),'Date Table'[Working Day] = 1 &&
'Date Table'[Date] <= [Latest Date Loaded]))
/
CALCULATE(
DISTINCTCOUNT('Date Table'[Date]),
DATESINPERIOD('Date Table'[Date],LASTDATE('Date Table'[Date]),-20, DAY),
FILTER(ALLSELECTED('Date Table'),'Date Table'[Working Day] = 1 &&
'Date Table'[Date] <= [Latest Date Loaded])))
 
 
Regards,
Lin
Community Support Team _ Lin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Goodness, I was way overthinking it. Thanks for your support Lin!

kotarosai
Helper II
Helper II

Please let me know if there are any other details that may help troubleshoot as well. Thanks!

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.