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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
Anonymous
Not applicable

I need to get data from previous row based on multiple columns

I need to calculate time taken by each user in seconds at each step for a particular Brief Id from below data set 

 

   (DD-MM-YYYY HH:MM:SS)
Brief IdAction BySeq. No.Created OnAction Date
Brief-000101Person A119-09-2023 08:00:0119-09-2023 08:00:59
Brief-000101Person B219-09-2023 08:00:0119-09-2023 08:10:15
Brief-000101Person C319-09-2023 08:00:0119-09-2023 09:35:45
Brief-000101Person D419-09-2023 08:00:0119-09-2023 13:19:01
Brief-000101Person E519-09-2023 08:00:0119-09-2023 16:32:26
Brief-000102Person X118-08-2023 15:30:4918-08-2023 15:31:08
Brief-000102Person Y218-08-2023 15:30:4918-08-2023 17:35:18
Brief-000102Person Z318-08-2023 15:30:4918-08-2023 18:55:58
Brief-000102Person X418-08-2023 15:30:4919-08-2023 13:01:12
Brief-000102Person Z518-08-2023 15:30:4919-08-2023 14:49:22

 

Bonus 1: Is there a way to factor out weekends (sat & sun) from the time taken calculation

Bonus 2: Is there a way to factor out weekends & company holidays imported from another excel/table

Bonus 3: Is there a way to factor out non working hours based on office hours imported from another excel/table

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Anonymous ,

Create a calculated column called Previous Action Date that returns the Action Date of the previous row for each Brief Id. You can use the EARLIER function to refer to an earlier row context. For example:

Previous Action Date =
CALCULATE (
    MAX ( 'Table'[Action Date] ),
    FILTER (
        'Table',
        'Table'[Brief Id] = EARLIER ( 'Table'[Brief Id] )
            && 'Table'[Seq. No.]
                = EARLIER ( 'Table'[Seq. No.] ) - 1
    )
)

Create another calculated column called Time Taken that returns the difference in seconds between the Action Date and the Previous Action Date for each row. You can use the DATEDIFF function to calculate the difference. For example:

Time Taken =
DATEDIFF ( 'Table'[Previous Action Date], 'Table'[Action Date], SECOND )

 

To exclude weekends (Saturday and Sunday) from the time taken calculation, you can use the WEEKDAY function to check the day of the week for each date and subtract the number of weekend days from the difference. For example:

Time Taken (Excluding Weekends) =
VAR Diff =
    DATEDIFF ( 'Table'[Previous Action Date], 'Table'[Action Date], DAY )
VAR StartDay =
    WEEKDAY ( 'Table'[Previous Action Date], 2 )
VAR EndDay =
    WEEKDAY ( 'Table'[Action Date], 2 )
VAR WeekendDays =
    INT ( Diff / 7 ) * 2
        + IF ( MOD ( Diff, 7 ) + StartDay > 6, 2, 0 )
        + IF ( AND ( MOD ( Diff, 7 ) + StartDay > 5, EndDay < StartDay ), -1, 0 )
RETURN
    DATEDIFF ( 'Table'[Previous Action Date], 'Table'[Action Date], SECOND ) - WeekendDays * 24 * 60 * 60

 

How to Get Your Question Answered Quickly 

 

If it does not help, please provide more details with your desired output and pbix file without privacy information (or some sample data) .

 

Best Regards
Community Support Team _ Rongtie

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

1 REPLY 1
Anonymous
Not applicable

Hi @Anonymous ,

Create a calculated column called Previous Action Date that returns the Action Date of the previous row for each Brief Id. You can use the EARLIER function to refer to an earlier row context. For example:

Previous Action Date =
CALCULATE (
    MAX ( 'Table'[Action Date] ),
    FILTER (
        'Table',
        'Table'[Brief Id] = EARLIER ( 'Table'[Brief Id] )
            && 'Table'[Seq. No.]
                = EARLIER ( 'Table'[Seq. No.] ) - 1
    )
)

Create another calculated column called Time Taken that returns the difference in seconds between the Action Date and the Previous Action Date for each row. You can use the DATEDIFF function to calculate the difference. For example:

Time Taken =
DATEDIFF ( 'Table'[Previous Action Date], 'Table'[Action Date], SECOND )

 

To exclude weekends (Saturday and Sunday) from the time taken calculation, you can use the WEEKDAY function to check the day of the week for each date and subtract the number of weekend days from the difference. For example:

Time Taken (Excluding Weekends) =
VAR Diff =
    DATEDIFF ( 'Table'[Previous Action Date], 'Table'[Action Date], DAY )
VAR StartDay =
    WEEKDAY ( 'Table'[Previous Action Date], 2 )
VAR EndDay =
    WEEKDAY ( 'Table'[Action Date], 2 )
VAR WeekendDays =
    INT ( Diff / 7 ) * 2
        + IF ( MOD ( Diff, 7 ) + StartDay > 6, 2, 0 )
        + IF ( AND ( MOD ( Diff, 7 ) + StartDay > 5, EndDay < StartDay ), -1, 0 )
RETURN
    DATEDIFF ( 'Table'[Previous Action Date], 'Table'[Action Date], SECOND ) - WeekendDays * 24 * 60 * 60

 

How to Get Your Question Answered Quickly 

 

If it does not help, please provide more details with your desired output and pbix file without privacy information (or some sample data) .

 

Best Regards
Community Support Team _ Rongtie

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

 

 

 

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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