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

Preparing for a certification exam? Ask exam experts all your questions on May 15th. Register now.

Reply
KiKa
New Member

Calculate days between order date of order n and order n+1 of each customers in Power BI

How can I calculate the number of days between order n and order n+1 for each customer in Power BI?

I want to show and analyze the timespan*(in the day)* between first and second, second and third, etc orders.

 

222.JPG

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @KiKa ,

You can create a calculated column as below to get it:

Number of days = 
VAR _nextodate =
    CALCULATE (
        MIN ( 'Table'[order date] ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[user id] = EARLIER ( 'Table'[user id] )
                && 'Table'[order id] > EARLIER ( 'Table'[order id] )
        )
    )
RETURN  
    DATEDIFF ( 'Table'[order date], _nextodate, DAY )

yingyinr_0-1661239920848.png

Best Regards

View solution in original post

3 REPLIES 3
Anonymous
Not applicable

Hi @KiKa ,

You can create a calculated column as below to get it:

Number of days = 
VAR _nextodate =
    CALCULATE (
        MIN ( 'Table'[order date] ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[user id] = EARLIER ( 'Table'[user id] )
                && 'Table'[order id] > EARLIER ( 'Table'[order id] )
        )
    )
RETURN  
    DATEDIFF ( 'Table'[order date], _nextodate, DAY )

yingyinr_0-1661239920848.png

Best Regards

amitchandak
Super User
Super User

@KiKa , Try a new column like

 

New column =
var _max = maxx(filter(Table, [User Id] =earlier([User Id]) && [Order Id] < earlier([Order Id]) ),[Order ID])
return
datediff([order Date] , maxx(filter(Table, [User Id] =earlier([User Id]) && [Order Id]= _max ),[Order Date]) , Day)+1

Full Power BI Video 20 Hours YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

@amitchandak 

 

Hey! I used your proposed solution above to solve a similar problem. However, the formula seems to struggle whenever the second order is in a new year or whenever a customer has placed two orders at the same day (see below example). In those cases it turns out negative.

 

ErikOmni_0-1665077209715.png

 

ErikOmni_2-1665077566667.png

 

ErikOmni_3-1665077662539.png

this is how the formula looks like with my data

 

Days between orders =
var _max = maxx(filter(OrderData, [CustomerID] =earlier([CustomerID]) && [OrderID] < earlier([OrderID]) ),[OrderID])
return
datediff([OrderDate] , maxx(filter(OrderData, [CustomerID] =earlier([CustomerID]) && [OrderID]= _max ),[OrderDate]) , Day)+1


Any ideas? Thanks!
 
 

 

 

 

Helpful resources

Announcements
PBIApril_Carousel

Power BI Monthly Update - April 2025

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

Notebook Gallery Carousel1

NEW! Community Notebooks Gallery

Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.

April2025 Carousel

Fabric Community Update - April 2025

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