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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
Lior0707
Frequent Visitor

How To Calculate Difference Between Dates in Same Column excluding weekends

Hi All ,

How To Calculate Difference Between Dates in Same Column excluding weekends.

 

Thank You 

 

Lior

 

 

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

Hi @Lior0707 ,

According to your description, @Greg_Deckler  gave a good solution on dates in two columns.

You mentioned that your dates are in same column. In this case, there are different solutions based on different data.

1. If the column only have two date rows.

vkalyjmsft_0-1652428377117.png

First add an index column in Power Query, then create a measure.

Date diff =
VAR Calendar1 =
    CALENDAR (
        MAXX ( FILTER ( ALL ( 'Table' ), 'Table'[Index] = 1 ), 'Table'[Date] ),
        MAXX ( FILTER ( ALL ( 'Table' ), 'Table'[Index] = 2 ), 'Table'[Date] )
    )
VAR Calendar2 =
    ADDCOLUMNS ( Calendar1, "WeekDay", WEEKDAY ( [Date], 2 ) )
RETURN
    COUNTX ( FILTER ( Calendar2, [WeekDay] < 6 ), [Date] )

Get the result.

vkalyjmsft_3-1652429353573.png

2. If there are multiple rows of dates in the column, and you want to compare the difference between every two rows of dates.

vkalyjmsft_2-1652429308446.png

First add an index column in Power Query, then create a measure.

Date diff2 =
VAR Calendar1 =
    CALENDAR (
        MAX ( 'Table'[Date] ),
        IF (
            MAX ( 'Table'[Index] ) <> MAXX ( ALL ( 'Table' ), 'Table'[Index] ),
            MAXX (
                FILTER ( ALL ( 'Table' ), 'Table'[Index] = MAX ( 'Table'[Index] ) + 1 ),
                'Table'[Date]
            ),
            MAX ( 'Table'[Date] )
        )
    )
VAR Calendar2 =
    ADDCOLUMNS ( Calendar1, "WeekDay", WEEKDAY ( [Date], 2 ) )
RETURN
    COUNTX ( FILTER ( Calendar2, [WeekDay] < 6 ), [Date] )

Get the result.

vkalyjmsft_4-1652429414143.png

I attach my sample below for reference.

 

Best Regards,
Community Support Team _ kalyj

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

2 REPLIES 2
v-yanjiang-msft
Community Support
Community Support

Hi @Lior0707 ,

According to your description, @Greg_Deckler  gave a good solution on dates in two columns.

You mentioned that your dates are in same column. In this case, there are different solutions based on different data.

1. If the column only have two date rows.

vkalyjmsft_0-1652428377117.png

First add an index column in Power Query, then create a measure.

Date diff =
VAR Calendar1 =
    CALENDAR (
        MAXX ( FILTER ( ALL ( 'Table' ), 'Table'[Index] = 1 ), 'Table'[Date] ),
        MAXX ( FILTER ( ALL ( 'Table' ), 'Table'[Index] = 2 ), 'Table'[Date] )
    )
VAR Calendar2 =
    ADDCOLUMNS ( Calendar1, "WeekDay", WEEKDAY ( [Date], 2 ) )
RETURN
    COUNTX ( FILTER ( Calendar2, [WeekDay] < 6 ), [Date] )

Get the result.

vkalyjmsft_3-1652429353573.png

2. If there are multiple rows of dates in the column, and you want to compare the difference between every two rows of dates.

vkalyjmsft_2-1652429308446.png

First add an index column in Power Query, then create a measure.

Date diff2 =
VAR Calendar1 =
    CALENDAR (
        MAX ( 'Table'[Date] ),
        IF (
            MAX ( 'Table'[Index] ) <> MAXX ( ALL ( 'Table' ), 'Table'[Index] ),
            MAXX (
                FILTER ( ALL ( 'Table' ), 'Table'[Index] = MAX ( 'Table'[Index] ) + 1 ),
                'Table'[Date]
            ),
            MAX ( 'Table'[Date] )
        )
    )
VAR Calendar2 =
    ADDCOLUMNS ( Calendar1, "WeekDay", WEEKDAY ( [Date], 2 ) )
RETURN
    COUNTX ( FILTER ( Calendar2, [WeekDay] < 6 ), [Date] )

Get the result.

vkalyjmsft_4-1652429414143.png

I attach my sample below for reference.

 

Best Regards,
Community Support Team _ kalyj

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

Greg_Deckler
Super User
Super User

@Lior0707 Net Work Days - Microsoft Power BI Community


Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel

Power BI Monthly Update - May 2024

Check out the May 2024 Power BI update to learn about new features.

Top Kudoed Authors