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

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes! Register now.

Reply
Wirestat
Frequent Visitor

Find Order Duration based on Start Stop time

Hello, please can you help to find order duration based on starting and finishing time example like in column duration. 

Order idFromToDuration
023:0023:03 
130699323:0323:03 
130699323:0323:06 
130699323:2223:33 
130699323:3323:33 
130699323:3423:35 
130699323:3523:37 
130699323:3823:39 
130699323:4223:43 
130699323:4323:4300:40
023:4323:44 
130530023:4423:45 
130530023:4523:46 
130530023:4723:47 
130530023:4823:49 
130530023:5423:54 
130530023:5423:55 
130530023:5623:59 
130530023:5900:00 
130530000:0000:01 
130530000:0200:03 
130530000:0300:03 
130530000:0400:04 
130530000:0400:07 
130530000:0700:07 
130530000:0700:08 
130530000:0800:0900:25
000:0900:10 
130701200:5300:54 
130701200:5400:55 
130701200:5600:58 
130701201:0201:0500:12
001:0501:05 
130703101:0501:05 
130703101:0601:06 
130703101:1101:11 
130703101:1301:14 
130703101:1901:42 
130703101:4401:45 
130703101:4501:46 
130703101:4601:4600:41
3 REPLIES 3
tamerj1
Super User
Super User

Hi @Wirestat 
Please try 

Duration (Minutes) =
SUMX (
    VALUES ( 'Table'[Order ID] ),
    VAR CurrentIDTable =
        CALCULATETABLE ( 'Table', ALLEXCEPT ( 'Table', 'Table'[Order ID] ) )
    VAR FirstStart =
        MINX ( CurrentIDTable, 'Table'[From] )
    VAR LastEnd =
        MAXX ( CurrentIDTable, 'Table'[To] )
    RETURN
        DATEDIFF ( FirstStart, LastEnd, MINUTE )
)
Anonymous
Not applicable

Hi  @Wirestat ,

 

 

Here are the steps you can follow:

1. . In Power Query -- Create Indices for the two tables -- Add Column – Index Column – From 1.

vyangliumsft_0-1677033581035.png

2. Create calculated column.

Rank =
RANKX(
    FILTER(ALL('Table'),'Table'[Order id]=EARLIER('Table'[Order id])),[Index],,ASC)
Flag =
VAR _mindate =
    MINX (
        FILTER (
            ALL ( 'Table' ),
            'Table'[Order id] = EARLIER ( 'Table'[Order id] )
                && 'Table'[Rank]
                    = MINX (
                        FILTER ( ALL ( 'Table' ), 'Table'[Order id] = EARLIER ( 'Table'[Order id] ) ),
                        [Rank]
                    )
        ),
        [From]
    )
VAR _maxdate =
    MAXX (
        FILTER (
            ALL ( 'Table' ),
            'Table'[Order id] = EARLIER ( 'Table'[Order id] )
                && 'Table'[Rank]
                    = MAXX (
                        FILTER ( ALL ( 'Table' ), 'Table'[Order id] = EARLIER ( 'Table'[Order id] ) ),
                        [Rank]
                    )
        ),
        [To]
    )
VAR _datediff =
    DATEDIFF ( _mindate, _maxdate, MINUTE )
RETURN
    IF (
        'Table'[Order id] = 0,
        BLANK (),
        IF (
            VALUE ( LEFT ( _mindate, FIND ( ":", _mindate ) - 1 ) )
                < VALUE ( LEFT ( _maxdate, FIND ( ":", _maxdate ) - 1 ) ),
            _datediff + 24 * 60,
            _datediff
        )
    )
Time =
var _hour=
QUOTIENT('Table'[Flag],60)
var _minute=
MOD('Table'[Flag],60)
return
IF(
    [Flag]=BLANK(),BLANK(),
IF(
    'Table'[Rank]=
    MAXX(FILTER(ALL('Table'),'Table'[Order id]=EARLIER('Table'[Order id])),[Rank]),
TIME(
    _hour,_minute,0),BLANK()))

3. Result:

vyangliumsft_1-1677033581038.png

 

Best Regards,

Liu Yang

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

Hello @Anonymous 

Thank you but i get an error

Wirestat_0-1677059744007.png

 

Helpful resources

Announcements
September Power BI Update Carousel

Power BI Monthly Update - September 2025

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

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.