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
gunasai
Helper I
Helper I

Difference between two dates

Hi guys,

I have 2 tables as follows,

 

Order table

Order NumberOrder Date
11111/1/2020
22221/5/2020
33331/10/2020
44441/20/2020

 

Invoice table

Order NumberInvoice_dateShipment_num
11111/30/20201
11112/5/20202
22221/20/20201
22221/25/20202

 

Both these tables have a 1-many relationship as you can see above.

 

How do I create a measure to find the difference between the dates (Invoice Date - Order Date) to find the number of days? I want it for shipment_num = 1 only.

 

I tried,

Order Completion Time in days = DATEDIFF(Min('Order Table'[Order Date]), Max('Invoice Table'[Invoice Date]), DAY)
and then filtered shipment_num = 1 in the visual table.
 
I am not able to aggregate to find the average no. of days. I am not able to summarize it after the calculation.
 
Any help would be appreciated.
 
Thanks!
2 ACCEPTED SOLUTIONS
ebeery
Memorable Member
Memorable Member

@gunasai  are you attempting to do this in a measure or a calculated column?

One way to do it would be with a calculated column, added to the invoice table.  Formula might look something like:

Order Completion Time in Days = 

VAR _Invoice_Date = 'Invoice Table'[Invoice_date]
VAR _Order_Date = LOOKUPVALUE('Order Table'[Order Date],'Order Table'[Order Number],'Invoice Table'[Order Number])
VAR _Result = DATEDIFF(_Order_Date, _Invoice_Date, DAY)

Return
_Result

ebeery_1-1636417311960.png

 

View solution in original post

@gunasai a similar approach could be used with a measure in a table visual, but in order for it to work properly you would need to ensure that only a single "Invoice_Date" and "Order Number" are in "context" (in other words, you need to include Order Number and Invoice Date in your visual). 

I would also use SELECTEDVALUE() to ensure the measure doesn't return anything if there are more than one Order Number and Invoice Date in context.

Order Completion Time in Days (measure) =
VAR _Invoice_Date =
    SELECTEDVALUE ( 'Invoice Table'[Invoice_date] )
VAR _Order_Date =
    LOOKUPVALUE (
        'Order Table'[Order Date],
        'Order Table'[Order Number], SELECTEDVALUE ( 'Invoice Table'[Order Number] )
    )
VAR _Result =
    DATEDIFF ( _Order_Date, _Invoice_Date, DAY )
RETURN
    _Result

ebeery_0-1636418872054.png

 

View solution in original post

6 REPLIES 6
ebeery
Memorable Member
Memorable Member

@gunasai  are you attempting to do this in a measure or a calculated column?

One way to do it would be with a calculated column, added to the invoice table.  Formula might look something like:

Order Completion Time in Days = 

VAR _Invoice_Date = 'Invoice Table'[Invoice_date]
VAR _Order_Date = LOOKUPVALUE('Order Table'[Order Date],'Order Table'[Order Number],'Invoice Table'[Order Number])
VAR _Result = DATEDIFF(_Order_Date, _Invoice_Date, DAY)

Return
_Result

ebeery_1-1636417311960.png

 

THIS WORKED!!!
Thank you so much!

I never did a calculated column before when there are two tables. Thank you so much for this again!

Just out of curiosity to learn, how would I do the same if I wanted to do a measure?

@gunasai 

you can also try this

Measure = DATEDIFF(max('Order'[Order Date]),MAXX(FILTER(Invoice,Invoice[Shipment_num]=1),'Invoice'[Invoice_date]),DAY)

1.PNG

pls see the attachment below





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Thank you!

@gunasai a similar approach could be used with a measure in a table visual, but in order for it to work properly you would need to ensure that only a single "Invoice_Date" and "Order Number" are in "context" (in other words, you need to include Order Number and Invoice Date in your visual). 

I would also use SELECTEDVALUE() to ensure the measure doesn't return anything if there are more than one Order Number and Invoice Date in context.

Order Completion Time in Days (measure) =
VAR _Invoice_Date =
    SELECTEDVALUE ( 'Invoice Table'[Invoice_date] )
VAR _Order_Date =
    LOOKUPVALUE (
        'Order Table'[Order Date],
        'Order Table'[Order Number], SELECTEDVALUE ( 'Invoice Table'[Order Number] )
    )
VAR _Result =
    DATEDIFF ( _Order_Date, _Invoice_Date, DAY )
RETURN
    _Result

ebeery_0-1636418872054.png

 

Perfect!
Thank you!

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