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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
AntonioCarl
Helper I
Helper I

Transform data to sum working hours

Hi, 

I've got a table 

Employee_idDateTimeType
63002.01.2024 00:00:0009:45:50IN
63002.01.2024 00:00:0017:02:40OUT
63013.02.2024 00:00:0016:06:30OUT
63017.09.2024 00:00:0006:37:50IN
63017.09.2024 00:00:0008:07:30OUT
63017.09.2024 00:00:0008:21:00IN
63017.09.2024 00:00:0016:20:00

 

 

 

 

For each employee_id and each date I need to find IN and OUT pairs. 

If there's pair IN and OUT return IN and OUT in pair-rows. In my example theres going to be one row for 02.01.2024 but two rows for 17.09.2024 and it means that employee left company in middle of the day. 

Theres also case that he forgot to Clock in or clock out. Then I need to add proper description to new column. 

I've tried to do write it myself  but failed.  


What I want to achieve is basically something like that. 

Employee_idDateINOUTDESCRIPTION
63002.01.2024 00:00:0009:45:5017:02:40 
63013.02.2024 00:00:00null16:06:30NOT CLOCKED IN 
63017.09.2024 00:00:0006:37:5008:07:30 
63017.09.2024 00:00:0008:21:0016:20:00 
1 ACCEPTED SOLUTION
Omid_Motamedise
Super User
Super User

IT was really interesting question,

Find the solution as bellow

let
    Source = Excel.CurrentWorkbook(){[Name="Table5"]}[Content],
    #"Added Index" = Table.AddIndexColumn(Source, "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each if [Index]=0 or (not (Source[Type]{[Index]}="OUT" and Source[Type]{[Index]-1}="IN")) then [Index] else [Index]-1),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Custom"}, {{"values", each _}}),
    #"Uppercased Text" = Table.TransformColumns(#"Grouped Rows",{{"values", each Table.RemoveColumns(_,{"Index","Custom"})}}),
    Custom1 = Table.TransformColumns( #"Uppercased Text",{{"values", each Table.Pivot(_,{"IN","OUT"},"Type","Time")}}),
    Custom2 = Table.TransformColumns( Custom1,{{"values", each Table.AddColumn(_,"Description", (x)=> if x[IN]=null then "NOT CLOCKED IN" else if x[OUT]=null then "NOT CLOCKED OUT" else "")}}),
    #"Removed Columns" = Table.RemoveColumns(Custom2,{"Custom"}),
    #"Expanded values" = Table.ExpandTableColumn(#"Removed Columns", "values", {"Employee_id", "Date", "IN", "OUT", "Description"}, {"Employee_id", "Date", "IN", "OUT", "Description"})
in
    #"Expanded values"

If my answer helped solve your issue, please consider marking it as the accepted solution.

View solution in original post

6 REPLIES 6
AlienSx
Super User
Super User

let
    idx = Table.AddIndexColumn(your_table, "idx"),
    gkl = Table.Group(
        idx, 
        {"Employee_id", "Date", "Type", "idx"}, 
        {"x", (x) => Record.FromList(x[Time], x[Type]) & 
            [DESCRIPTION = if Table.RowCount(x) = 2 then null else "NOT CLOCKED " & List.Difference({"IN", "OUT"}, x[Type]){0}]},
        GroupKind.Local,
        (s, c) => Number.From(
            List.AnyTrue(
                {
                    s[Employee_id] <> c[Employee_id], 
                    s[Date] <> c[Date], 
                    c[Type] = "IN", 
                    s[Type] = "IN" and c[idx] - s[idx] > 1, 
                    s[Type] = c[Type]
                }
            )
        )
    ),
    xpand = Table.ExpandRecordColumn(gkl, "x", {"IN", "OUT", "DESCRIPTION"})[[Employee_id], [Date], [IN], [OUT], [DESCRIPTION]]
in
    xpand
Omid_Motamedise
Super User
Super User

IT was really interesting question,

Find the solution as bellow

let
    Source = Excel.CurrentWorkbook(){[Name="Table5"]}[Content],
    #"Added Index" = Table.AddIndexColumn(Source, "Index", 0, 1, Int64.Type),
    #"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each if [Index]=0 or (not (Source[Type]{[Index]}="OUT" and Source[Type]{[Index]-1}="IN")) then [Index] else [Index]-1),
    #"Grouped Rows" = Table.Group(#"Added Custom", {"Custom"}, {{"values", each _}}),
    #"Uppercased Text" = Table.TransformColumns(#"Grouped Rows",{{"values", each Table.RemoveColumns(_,{"Index","Custom"})}}),
    Custom1 = Table.TransformColumns( #"Uppercased Text",{{"values", each Table.Pivot(_,{"IN","OUT"},"Type","Time")}}),
    Custom2 = Table.TransformColumns( Custom1,{{"values", each Table.AddColumn(_,"Description", (x)=> if x[IN]=null then "NOT CLOCKED IN" else if x[OUT]=null then "NOT CLOCKED OUT" else "")}}),
    #"Removed Columns" = Table.RemoveColumns(Custom2,{"Custom"}),
    #"Expanded values" = Table.ExpandTableColumn(#"Removed Columns", "values", {"Employee_id", "Date", "IN", "OUT", "Description"}, {"Employee_id", "Date", "IN", "OUT", "Description"})
in
    #"Expanded values"

If my answer helped solve your issue, please consider marking it as the accepted solution.

Worked like a charm. Thank you! 

You are welcome, and thanks for sharing your lovely question.


If my answer helped solve your issue, please consider marking it as the accepted solution.
ronrsnfld
Super User
Super User

Your last line has no entry for Description

How do you know that it should by an OUT? 

What if he negelected to log OUT earlier in the day and this is really an IN and he's either still there or forgot to log OUT for the second time that day?

lbendlin
Super User
Super User

Yeah, what could possibly go wrong?  What if you have two IN events ?

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

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