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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
moosepng
Helper II
Helper II

DATEDIFF between DateTime Values by ID

I have a Table_A, which tracks the DateTime of status changes.

DateTimeIDEntryExit
29/10/2020 14:25100110
01/12/2020 15:30100210
05/02/2021 12:00100101
15/04/2021 21:45100201



I want to calculate the amount of time between Entry and Exit for each ID (TimeSpent).

DateTimeIDEntryExitTimeSpent
29/10/2020 14:25100110null
01/12/2020 15:30100210null
05/02/2021 12:0010010199
15/04/2021 21:45100201

135


Something like this

 

 

TimeSpent = 
DATEDIFF(
  FILTER('TableA'[DateTime], Entry = 1),
  FILTER('TableA'[DateTime], Exit = 1),
  Day
)

 

 


I get the following error message "The expression refers to multiple columns. Multiple columns cannot be converted to a scalar value."

I doubt very much that FILTER is the right way to identify cases for the calculation... I've tried CALCULATE but that didn't work either.

Any ideas?

Similar issues:
https://community.powerbi.com/t5/Desktop/DateDiff-with-Filter-based-on-specific-value/m-p/1366481#M5...
https://community.powerbi.com/t5/Desktop/using-datediff-with-filters/m-p/528938#M247760
https://community.powerbi.com/t5/DAX-Commands-and-Tips/DATEDIFF-with-filter/m-p/769728#M3623

1 ACCEPTED SOLUTION
amitchandak
Super User
Super User

@moosepng , Try a measure like

 

averageX(values(Table[ID]), calculate(datediff(minx(filter(Table, Table[Entry] =1), [DateTime]),maxx(filter(Table, Table[exit] =1), [DateTime]),minute)))

View solution in original post

6 REPLIES 6
moosepng
Helper II
Helper II

Thank you both for getting back to me. I'll try out the solutions and get back to you 🙂

Jihwan_Kim
Super User
Super User

Hi, @moosepng 

Please check the below picture and the sample pbix file's link down below.

 

Picture5.png

 

Time Spent Measure =
VAR currentid =
MAX ( 'Table'[ID] )
VAR entrydatetime =
CALCULATE (
MAX ( 'Table'[DateTime] ),
FILTER ( ALL ( 'Table' ), 'Table'[ID] = currentid && 'Table'[Entry] = 1 )
)
RETURN
IF (
ISFILTERED ( 'Table'[ID] ),
IF (
SELECTEDVALUE ( 'Table'[Exit] ) = 1,
DATEDIFF ( entrydatetime, SELECTEDVALUE ( 'Table'[DateTime] ), DAY ),
"null"
)
)
 
 
 
 

Hi, My name is Jihwan Kim.


If this post helps, then please consider accept it as the solution to help other members find it faster, and give a big thumbs up.


Linkedin: linkedin.com/in/jihwankim1975/

Twitter: twitter.com/Jihwan_JHKIM

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Thanks!
downloaded the pbix. and your solution works for the sample data. However, it returned null values for my actual dataset.
must be the if()? could be that my IDs are text not numerical?

Hi, @moosepng 

Thank you for your feedback.

in my sample, ID is a number format.

If your ID column is a text format, please try writing something like below.

 

"1"   "2"   ...

 

Thank you.

 

Hi, My name is Jihwan Kim.

 

If this post helps, then please consider accept it as the solution to help other members find it faster, and give a big thumbs up.

 

Linkedin: linkedin.com/in/jihwankim1975/

Twitter: twitter.com/Jihwan_JHKIM

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


amitchandak
Super User
Super User

@moosepng , Try a measure like

 

averageX(values(Table[ID]), calculate(datediff(minx(filter(Table, Table[Entry] =1), [DateTime]),maxx(filter(Table, Table[exit] =1), [DateTime]),minute)))

Hi Amitchandak,
Is it possible to filter this measure [TimeSpent] by a Date table 'Date'?
You would need to specify in the Measure that the filter applies to the Exit DateTime. Or possibly ignore the lesser date with something like ...

FILTER(ALL('Date'[DateTime]),'Date'[DateTime]<=MAX('Date'[DateTime]))

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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