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
Anonymous
Not applicable

Measure to calculate number of employed days in period

Hi there

Love PowerQuery, but for some reason I can't get my head around DAX. 

 

Anyway - I have an Employee table where I have an employment start and termination date listed. For any given period I'd like to calculate the number of days the worker has been employed, taking the start and termination dates into account.

So far I have the below, but a few issues...
1) It complains about my True/False expression. What am I doing wrong here?
2) How can I deduct 1 day from STDATE_EMP (when used in EXCL_DAYS)? Tried using DATEADD but it was expecting a column?

3)  The SELECTEDRANGE is right now a single column table. Can I somehow filter this? I'm thinking a combination of VALUES and FILTER...?

Sorry that's a lot but really struggling.


 

WORKERS_DAYS =

VAR STDATE = CALCULATE(MIN(Dates[Date]))
VAR NDDATE = CALCULATE(MAX(Dates[Date]))

-- SINGLE COLUMN TABLE WITH ALL DATES IN MONTH:
VAR SELECTEDRANGE = CALENDAR(STDATE, NDDATE)

-- WORKERS ACTUAL STARTING DATE
VAR STDATE_EMP = CALCULATE(MIN('NAV - Employee'[Employment Date]))

-- DECIDE IF WORKER STARTED AFTER THE PERIODS START DATE
VAR LATESTART_EMP = STDATE_EMP > STDATE

-- SINGLE COLUMN TABLE WITH POSSIBLE DATES TO EXCLUDE
VAR EXCL_DAYS = CALENDAR(STDATE, STDATE_EMP)

-- EXCLUDE DAYS FROM SELECTEDRANGE
VAR EXCLUDEDDAYS = IF(LATESTART_EMP, EXCEPT(SELECTEDRANGE, EXCL_DAYS), SELECTEDRANGE)

RETURN CALCULATE(COUNTROWS(), EXCLUDEDDAYS)
1 ACCEPTED SOLUTION
johnt75
Super User
Super User

The below assumes that you have a column called Is Working Day in your date table, which contains a 1 if it is a working day and 0 otherwise.

Employed days =
SUMX (
    Employee,
    VAR StartDate = Employee[Start date]
    VAR EndDate = Employee[Termination date]
    VAR NumDays =
        CALCULATE (
            SUM ( 'Date'[Is Working Day] ),
            KEEPFILTERS ( DATESBETWEEN ( 'Date'[Date], StartDate, EndDate ) )
        )
    RETURN
        NumDays
)

View solution in original post

2 REPLIES 2
johnt75
Super User
Super User

The below assumes that you have a column called Is Working Day in your date table, which contains a 1 if it is a working day and 0 otherwise.

Employed days =
SUMX (
    Employee,
    VAR StartDate = Employee[Start date]
    VAR EndDate = Employee[Termination date]
    VAR NumDays =
        CALCULATE (
            SUM ( 'Date'[Is Working Day] ),
            KEEPFILTERS ( DATESBETWEEN ( 'Date'[Date], StartDate, EndDate ) )
        )
    RETURN
        NumDays
)
Anonymous
Not applicable

Thanks so much! Really appreciate it.

Helpful resources

Announcements
November Fabric Update Carousel

Fabric Monthly Update - November 2025

Check out the November 2025 Fabric update to learn about new features.

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

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.

Users online (27)