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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Anonymous
Not applicable

Slicer based datediff

Hello,

 

I have been trying to compute this problem for a while now and without any progress. I managed to do a workaround but am professionally curious whether it is possible to compute in PowerBI directly.

 

I have a table with box IDs, start time, end time and time difference between start time and end time for each row, where start and end time mark the time interval during which a box was full. What I am trying to compute is the portion of time during which the box is full based on a slicer. (For example what portion of time was the box full between 2nd and 5th May 2019?). 

 

The calculation works fine if the slicer is in original position, i.e. the data is not sliced. But when I move the slicer, the calucaltion gets distorted because originally I based my calculation on the time difference column. How can I compute time difference for each row in PowerBI measure? For example: The box is full from 1st May till 7th May and I move the slicer to be from 3rd till 5th May. Hence, the result should give me that this box was 100% full. But I need to calculate that if MIN Selected value of slicer is larger than start time, calculate DATEDIFF(MIN selected value, end time) etc.. But DATEDIFF does not work on single rows. Is there a similar function working on rows? Any other ideas for a workaround? Below I share a sample of my data.

 

Sample data. There can be multiple rows with the same IDSample data. There can be multiple rows with the same ID

 

Thanks for any help!

1 ACCEPTED SOLUTION
v-xuding-msft
Community Support
Community Support

Hi @Anonymous ,

I create a sample that can be calculated duration between the selected date and the end date, or if it is not selected, calculated it between the start date and the end date. You can reference it to modify yours.

 

  1. Create a new table.
Table = CALENDAR(DATE(2019,1,1),DATE(2019,12,31))
selected time = FORMAT('Table'[Date],"hh:mm:ss")

Note: when you create the calendar table, you need to add the minimum date of the start date and the maximum of the end time.  And there is no relationship between the two tables.

1.png2.png

  1. Create a calculated column
start time = FORMAT(Table1[start],"hh:mm:ss")

end time = FORMAT(Table1[end],"hh:mm:ss")
date_diff_min = var a = DATEDIFF(Table1[start],Table1[end],DAY) var b = DATEDIFF(Table1[start time],Table1[end time],MINUTE) return a*24*60+b

3.jpg

  1. Create a measure
Measure =
var a = DATEDIFF(MIN('Table'[Date]),MAX(Table1[end]),DAY)
var b = DATEDIFF(MIN('Table'[selected time]),MAX(Table1[end time]),MINUTE)
var c = IF( MIN('Table'[Date]) > MAX(Table1[start]) && MIN('Table'[Date]) < MAX(Table1[end]), a*24*60+b, SUM(Table1[date_diff_min]))
return c

4.jpg5.png

Best Regards,

Xue Ding 

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

Best Regards,
Xue Ding
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
v-xuding-msft
Community Support
Community Support

Hi @Anonymous ,

I create a sample that can be calculated duration between the selected date and the end date, or if it is not selected, calculated it between the start date and the end date. You can reference it to modify yours.

 

  1. Create a new table.
Table = CALENDAR(DATE(2019,1,1),DATE(2019,12,31))
selected time = FORMAT('Table'[Date],"hh:mm:ss")

Note: when you create the calendar table, you need to add the minimum date of the start date and the maximum of the end time.  And there is no relationship between the two tables.

1.png2.png

  1. Create a calculated column
start time = FORMAT(Table1[start],"hh:mm:ss")

end time = FORMAT(Table1[end],"hh:mm:ss")
date_diff_min = var a = DATEDIFF(Table1[start],Table1[end],DAY) var b = DATEDIFF(Table1[start time],Table1[end time],MINUTE) return a*24*60+b

3.jpg

  1. Create a measure
Measure =
var a = DATEDIFF(MIN('Table'[Date]),MAX(Table1[end]),DAY)
var b = DATEDIFF(MIN('Table'[selected time]),MAX(Table1[end time]),MINUTE)
var c = IF( MIN('Table'[Date]) > MAX(Table1[start]) && MIN('Table'[Date]) < MAX(Table1[end]), a*24*60+b, SUM(Table1[date_diff_min]))
return c

4.jpg5.png

Best Regards,

Xue Ding 

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

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

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.