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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
Oceanbagel
Frequent Visitor

Rolling average of a measure by day of week

I have a measure that calculates the percent of table records meeting a threshold and I need to get the average of this measure for the last 4 occurrences of each weekday.

 

MEASURE = CALCULATE(COUNTROWS(ReportTable),ReportTable[Seconds] < 16) / COUNTROWS(ReportTable)

 

I have a rolling average of this measure that calculates the last 30 days:

30 DAY AVG =

VAR DateFilter =
DATESINPERIOD(
DateTable[Date],
MAX(DateTable[Date]),
-30,
DAY
)
VAR RollingSum =
CALCULATE(SUMX(ReportTable,[Measure])/COUNTROWS(ReportTable),DateFilter)
 
RETURN
RollingSum
 
My date table has day of week but it can't be used in DATESINPERIOD. I've tried a lot of different things but I'm stuck.
 
Any help would be greatly appreciated.
1 ACCEPTED SOLUTION
Oceanbagel
Frequent Visitor

I was able to figure it out. Added a values filter to the calculate portion of the measure. It seems so obvious now.

Last 4 DoW = 

VAR DateFilter =
DATESINPERIOD(
DateTable[Date],
MAX(DateTable[Date]),
-28,
DAY
)

VAR RollingSum =
CALCULATE(SUMX(ReportTable,[Measure])/COUNTROWS(ReportTable),DateFilter,VALUES(DateTable[DayofWeek]))
 
RETURN
RollingSum

View solution in original post

3 REPLIES 3
Oceanbagel
Frequent Visitor

I was able to figure it out. Added a values filter to the calculate portion of the measure. It seems so obvious now.

Last 4 DoW = 

VAR DateFilter =
DATESINPERIOD(
DateTable[Date],
MAX(DateTable[Date]),
-28,
DAY
)

VAR RollingSum =
CALCULATE(SUMX(ReportTable,[Measure])/COUNTROWS(ReportTable),DateFilter,VALUES(DateTable[DayofWeek]))
 
RETURN
RollingSum
amitchandak
Super User
Super User

@Oceanbagel , You need to have measure like examples

 

Rolling 30 = calculate(AverageX(Values('Date'[Date]),[Measure]),DATESINPERIOD('Date'[Date ],MAX('Date'[Date ]),-30,DAY))

 

Rolling 30 = calculate(AverageX(Values('Date'[Week Day]),[Measure]),DATESINPERIOD('Date'[Date ],MAX('Date'[Date ]),-30,DAY))

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

@amitchandak , thanks for helping with this. Unfortunately this is still giving the average over 30 successive days. I'm trying to get the average for the last 4 Sundays, Mondays, etc.

Helpful resources

Announcements
July PBI25 Carousel

Power BI Monthly Update - July 2025

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

Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 community update carousel

Fabric Community Update - June 2025

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