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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
chris886
Frequent Visitor

Help with Measure - Daily Average excluding weekends

Hello,

 

Hoping this is a simple solve, I just don't have the experience to figure it out yet.

 

My dataset has a 'Measure X' that represents a count of events. I'd like to create a measure that can calculate the daily average events for the previous 14 days, excluding any weekend days. Bonus points if there's a way to specifically make it also exclude US holidays (but I'm fine if that's not possible). We only get events on working days, so when I try to do just a simple relative date filter, the average gets diluted by the weekends/holidays.

 

Could someone help me with the DAX on this?

 

Thank you.

1 ACCEPTED SOLUTION
v-jingzhang
Community Support
Community Support

Hi @chris886 

 

It is recommended to prepare a calendar table with a WorkingDay column which has 1 for working days and 0 for weekends/holidays. Create a relationship between the original table and the calendar table on Date column. Then you can try the following measure

Avg of Measure X =
VAR _lastDate =
    TODAY ()
RETURN
    DIVIDE (
        CALCULATE (
            [Measure X],
            DATESINPERIOD ( 'Calendar'[Date], _lastDate, -14, DAY )
        ),
        CALCULATE (
            COUNT ( 'Calendar'[Date] ),
            DATESINPERIOD ( 'Calendar'[Date], _lastDate, -14, DAY ),
            'Calendar'[Working Day] = 1
        )
    )

 

I have created a sample attached at bottom. Hope it helps. 

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

2 REPLIES 2
v-jingzhang
Community Support
Community Support

Hi @chris886 

 

It is recommended to prepare a calendar table with a WorkingDay column which has 1 for working days and 0 for weekends/holidays. Create a relationship between the original table and the calendar table on Date column. Then you can try the following measure

Avg of Measure X =
VAR _lastDate =
    TODAY ()
RETURN
    DIVIDE (
        CALCULATE (
            [Measure X],
            DATESINPERIOD ( 'Calendar'[Date], _lastDate, -14, DAY )
        ),
        CALCULATE (
            COUNT ( 'Calendar'[Date] ),
            DATESINPERIOD ( 'Calendar'[Date], _lastDate, -14, DAY ),
            'Calendar'[Working Day] = 1
        )
    )

 

I have created a sample attached at bottom. Hope it helps. 

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

rsbin
Super User
Super User

@chris886 ,

DAX has a WEEKDAY function

https://docs.microsoft.com/en-us/dax/weekday-function-dax

If you are using a Date Table, you can create a Calculated Column and determine Weekday.

If not, simply create a new column in your data table.

Then add a FILTER to your Measure and exclude Days 6 and 7 (depending on which return_type you decide to use).

Hope this helps.

Regards,

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

September Power BI Update Carousel

Power BI Monthly Update - September 2025

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

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.

Top Solution Authors
Top Kudoed Authors