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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
hickkich
New Member

Define Shifts Where Weekend/Weekday Shifts Involve Different Hours

Hi, 

 

I am trying to create a column that determines if the event happened on a day or night shift.  Here is the column that I am trying to use to determine the shifts. 

hickkich_1-1677422238666.png

 

A week day shift is 8a-5p

A week night shift is 5p-8a

A weekend day shift is 8a-8p

A weekend night shift is 8p-8a

 

Of note, I found a similar thread where a user was trying to do this with a similar date column.  When I used their switch formulaI received an error that the first 6, is unexpected.

A shift = Mon-Friday 06:00:00-14:00:00

B shift = Mon-Friday 14:00:00-22:00:00

C shift = Sun-Fri 22:00:00-06:00:00

D shift = Sat and Sun 06:00:00-18:00:00

 

hickkich_1-1677423228655.png

 

 

Shift = SWITCH ( TRUE (), AND ( HOUR ( Table[EventTime] ) IN { 6, 7, 8, 9, 10, 11, 12, 13 }, WEEKDAY ( Table[EventTime] ) IN { 2, 3, 4, 5, 6 } ), "A", AND ( HOUR ( Table[EventTime] ) IN { 14, 15, 16, 17, 18, 19, 20, 21 }, WEEKDAY ( Table[EventTime] ) IN { 2, 3, 4, 5, 6 } ), "B", AND ( HOUR ( Table[EventTime] ) IN { 22, 23, 24, 1, 2, 3, 4, 5 }, WEEKDAY ( Table[EventTime] ) IN { 1, 2, 3, 4, 5, 6 } ), "C", AND ( HOUR ( Table[EventTime] ) IN { 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17 }, WEEKDAY ( Table[EventTime] ) IN { 6, 7 } ), "D" )

2 REPLIES 2
tamerj1
Super User
Super User

Hi @hickkich 
Please refer to attached sample file with the proposed solution.

You need to create a shift table as per the screenshot. You need to edit the same to suit your requirement as you can see that some times return blank values which means that apparently I don't fully understand the timings of the different shifts. 

With the help of the shifts table, the shift calculated column will become a simple DAX formula.

1.png2.png

Shift = 
MAXX ( 
    FILTER ( 
        Shifts,
        Shifts[Weekday Number] = WEEKDAY ( Data[CreationInstant], 2 )
            && TIMEVALUE ( Data[CreationInstant] ) >= Shifts[StartTime]
            && TIMEVALUE ( Data[CreationInstant] ) <= Shifts[EndTime]
    ),
    Shifts[Shift]
)
FreemanZ
Super User
Super User

hi @hickkich 

try like:

Shift = 
VAR _h =HOUR( TableName[CreationInstant] ) 
VAR _d = WEEKDAY ( TableName[CreationInstant], 2 )
VAR _condition1 = _h>=8 && _h <=17
VAR _condition2 = _d IN {6, 7}
RETURN
SWITCH ( 
    TRUE (), 
    _condition1&&NOT _condition2, 
    "week day shift",
    NOT _condition1&&NOT _condition2, 
    "week night shift",
    _condition1&&_condition2, 
    "weekend day shift",
    "weekend night shift"
)

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors