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
LEPR
Frequent Visitor

Restricted sum by day for opening time calculation

Hi everyone,

 

First time I couldn't find the answer directly on the forum, I will need the help of the community on this one !

 

I am working with data coming from multiple files that I merge in PBI.

At the end, my data looks like this : 

DayTimeStatusDuration
Day 18:00A54
Day 18:54B80
Day 110:14A200
Day 113:34A...
Day 115:55B 
Day 28:05A 
Day 2...A 
Day 2 B 
Day 216:15B 
Day 37:55A 
Day 3 A 
Day 3 B 
Day 3 B 
Day 3 B 
Day 317:10A 

 

I am trying to calculate the sum of the opening time of each day, so the difference between the minimum hour of the day (8:00 on day 1 for example), and the maximum hour of the day (15:55 for day 1 for example).

So I can easily make it work with MAX(Time)-MIN(Time) for a specific Day, but when I want to do it for multiple days I can't figure it out. I need to exclude the closed time inbetween the days, like between 15.55 on day 1 and 8.05 on day 2. 

Between day 1 and day 2, the result will have to be 7:55 + 8:10 = 16:05 of opening time. But with the min max function, I will get 40:15 ... So i need to restrict it by day somehow.

 

Thanks for helping out,

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

Hi @LEPR ,

 

According to your description, here are my steps you can follow as a solution.

(1) My test data is the same as yours.

(2) We can create two measures. 

open time = 
var _min =MINX(FILTER(ALL('Table'),'Table'[Day]=MAX('Table'[Day])),'Table'[Time])
var _max=MAXX(FILTER(ALL('Table'),'Table'[Day]=MAX('Table'[Day])),'Table'[Time])
return _max-_min
sum = SUMX(ALLSELECTED('Table'[Day]),'Table'[open time])

(3) Then the result is as follows.

vtangjiemsft_0-1684464683784.png

 

If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.

 

Best Regards,

Neeko Tang

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

2 REPLIES 2
Ashish_Mathur
Super User
Super User

Hi,

Clearly show the result you are expecting.  Also, if you have a Date column, share that as well.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
v-tangjie-msft
Community Support
Community Support

Hi @LEPR ,

 

According to your description, here are my steps you can follow as a solution.

(1) My test data is the same as yours.

(2) We can create two measures. 

open time = 
var _min =MINX(FILTER(ALL('Table'),'Table'[Day]=MAX('Table'[Day])),'Table'[Time])
var _max=MAXX(FILTER(ALL('Table'),'Table'[Day]=MAX('Table'[Day])),'Table'[Time])
return _max-_min
sum = SUMX(ALLSELECTED('Table'[Day]),'Table'[open time])

(3) Then the result is as follows.

vtangjiemsft_0-1684464683784.png

 

If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.

 

Best Regards,

Neeko Tang

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

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.