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

Trying to work out estimated finishing times for our warehouse

Hi,

 

I have a formula for calculating our estimated finishing time:

Total Totes / 700 = Time remaining

Time remaining + Now = Estimated Finsihing Time

 

The issue I am having is that everything is working off datetime and not just time.

For example, yesterday at 4pm the formual would be:

3426 / 700 = 4.8942 (which translates to roughly 4 hours and 53 mins)

4.8942 + 16:00:00 = 20:53:00 (estimated finishing time)

 

But running this now for yesterdays time gives me an answer of "12/05/2022 10:07:45"

Is there a way to do calculations without the date being involved?

or is there a simpler way to calculate time by adding decimals?

1 ACCEPTED SOLUTION

Hello @billhawley 

Thanks for sending across the data. The main issue with your measure is that it does not take into account the max time when the values are non blank correctly. As a result, it returns the max non-blank value, rather than the last non-blank value. I have managed to recreate your dataset and achieve the desired output. Please take a look : 

Table :  FinishingTimes

rohit_singh_4-1652362633564.png

 



1) Compute max non-blank time and extract the hour and minute components

rohit_singh_0-1652362275305.png

2) Compute each of the tote values. Please note the added filters where we compare the hour and the minute of the time value with those of the max time. This ensures only the last row is picked up

rohit_singh_1-1652362342481.png

3) Compute the total values, convert to hours, and find the finishing time

rohit_singh_2-1652362379997.png

rohit_singh_3-1652362538732.png

 

The measure is available below for your reference :

TotesSnapshot =

--Calculate the maximum non - blank time
var _maxtime = format(CALCULATE(MAX(FinishingTimes[Time]), FILTER(FinishingTimes, FinishingTimes[Totes] <> BLANK())), "hh:mm", "en-UK")

--Extract hour from maxtime
var _hour = left(_maxtime,2)

--Extract minute from maxtime
var _min = mid(_maxtime, 4, 2)

--Compute each tote
var Belt1Customer1Totes =
CALCULATE(MAX(FinishingTimes[Totes]),
FILTER(FinishingTimes, FinishingTimes[Belt] = "Belt 1" &&
FinishingTimes[Customer] = "Customer 1" &&
left(format(FinishingTimes[Time], "hh:mm", "en-UK"),2) = _hour &&
mid(format(FinishingTimes[Time], "hh:mm", "en-UK"),4,2) = _min))

var Belt1Customer2Totes =
CALCULATE(MAX(FinishingTimes[Totes]),
FILTER(FinishingTimes, FinishingTimes[Belt] = "Belt 1" &&
FinishingTimes[Customer] = "Customer 2" &&
left(format(FinishingTimes[Time], "hh:mm", "en-UK"),2) = _hour &&
mid(format(FinishingTimes[Time], "hh:mm", "en-UK"),4,2) = _min))

var Belt2Customer1Totes =
CALCULATE(MAX(FinishingTimes[Totes]),
FILTER(FinishingTimes, FinishingTimes[Belt] = "Belt 2" &&
FinishingTimes[Customer] = "Customer 1" &&
left(format(FinishingTimes[Time], "hh:mm", "en-UK"),2) = _hour &&
mid(format(FinishingTimes[Time], "hh:mm", "en-UK"),4,2) = _min))

var Belt2Customer2Totes =
CALCULATE(MAX(FinishingTimes[Totes]),
FILTER(FinishingTimes, FinishingTimes[Belt] = "Belt 2" &&
FinishingTimes[Customer] = "Customer 2" &&
left(format(FinishingTimes[Time], "hh:mm", "en-UK"),2) = _hour &&
mid(format(FinishingTimes[Time], "hh:mm", "en-UK"),4,2) = _min))

--Compute total values
var _totesnapshot = Belt1Customer1Totes + Belt1Customer2Totes + Belt2Customer1Totes + Belt2Customer2Totes

--Calculate hours in decimal
var _hours = round(convert(divide(_totesnapshot,700,0) ,STRING),4)

--Calculate finish time
var _Finishingtime = NOW() + TIME(datediff(TIME(0,0,0), TIME(_hours,0,0), HOUR),0,0)

RETURN
_Finishingtime
 
 

Kind regards,

Rohit


Please mark this answer as the solution if it resolves your issue.
Appreciate your kudos! 😊

View solution in original post

10 REPLIES 10
billhawley
Frequent Visitor

To add on as another example, this mornings numbers are:

705+680+578+21 = 1984

1984 / 700 = 2.834 (roughly 3 hours)

2.834 + NOW()

The answer I expect - 13:19

The answer Power BI is giving me - 15/05/2022 06:18:00

Hi @billhawley ,

Please try this : 

rohit_singh_0-1652348745506.png

Finishing time = NOW() + TIME(2.834,0,0)
 
You have to explicitly define the constituent time parts in order to get the correct time.
 

Kind regards,

Rohit


Please mark this answer as the solution if it resolves your issue.
Appreciate your kudos ! 😊

Hi Rohit,

 

That works, but only for static values, the number we need to add changes every 30mins based on another formula. I have swapped out 2.834 for the formula and added in the ,0,0 and I am not getting any errors but I am getting: 13/05/2022 02:06:41

Which is defintily not ~3 hours

Hi @billhawley,

Please try this :

Finishing time = NOW() + TIME(datediff(TIME(0,0,0), TIME(2.834,0,0), HOUR),0,0)
 
Replace the 2.834 with your formula.

Kind regards,

Rohit

I think I know what the problem may be.

In my formula I use LASTNONBLANK, instead of giving me the actual last non blank value it is giving me the highest value from each column.

 

Would you know the best way to pick the actual last non blank value from the table?

 

Thanks for your help so far!

Hi @billhawley ,

Would it be possible for you to share sample data? 

Kind regards,

Rohit

Hi Rohit,

billhawley_0-1652357265369.png

 

Not sure if you can see that but that is the total dataset.

My formula is:

 

TotesSnapshot = LASTNONBLANK(Belt1Customer1Totes,1) + LASTNONBLANK (Belt1Customer2Totes,1) + LASTNONBLANK(Belt2Customer1Totes,1) + LASTNONBLANK(Belt2Customer2Totes,1)

TotesSnapshot / 700 = Time in decimals

Now + Time = Estimated Finishing Time

 

What I would like it to do is use the numbers that are underlined, but the formula is instead using the largest numbers from those columns.

So it should look like this:

 TotesSnapshot = 806 + 286 + 1996 + 15 = 3103

3103 / 700 = 4.4328 (4 hours 25 mins 58 secs)

Now (13:15) + 4.4328 = ~17:40

 

Hello @billhawley 

Thanks for sending across the data. The main issue with your measure is that it does not take into account the max time when the values are non blank correctly. As a result, it returns the max non-blank value, rather than the last non-blank value. I have managed to recreate your dataset and achieve the desired output. Please take a look : 

Table :  FinishingTimes

rohit_singh_4-1652362633564.png

 



1) Compute max non-blank time and extract the hour and minute components

rohit_singh_0-1652362275305.png

2) Compute each of the tote values. Please note the added filters where we compare the hour and the minute of the time value with those of the max time. This ensures only the last row is picked up

rohit_singh_1-1652362342481.png

3) Compute the total values, convert to hours, and find the finishing time

rohit_singh_2-1652362379997.png

rohit_singh_3-1652362538732.png

 

The measure is available below for your reference :

TotesSnapshot =

--Calculate the maximum non - blank time
var _maxtime = format(CALCULATE(MAX(FinishingTimes[Time]), FILTER(FinishingTimes, FinishingTimes[Totes] <> BLANK())), "hh:mm", "en-UK")

--Extract hour from maxtime
var _hour = left(_maxtime,2)

--Extract minute from maxtime
var _min = mid(_maxtime, 4, 2)

--Compute each tote
var Belt1Customer1Totes =
CALCULATE(MAX(FinishingTimes[Totes]),
FILTER(FinishingTimes, FinishingTimes[Belt] = "Belt 1" &&
FinishingTimes[Customer] = "Customer 1" &&
left(format(FinishingTimes[Time], "hh:mm", "en-UK"),2) = _hour &&
mid(format(FinishingTimes[Time], "hh:mm", "en-UK"),4,2) = _min))

var Belt1Customer2Totes =
CALCULATE(MAX(FinishingTimes[Totes]),
FILTER(FinishingTimes, FinishingTimes[Belt] = "Belt 1" &&
FinishingTimes[Customer] = "Customer 2" &&
left(format(FinishingTimes[Time], "hh:mm", "en-UK"),2) = _hour &&
mid(format(FinishingTimes[Time], "hh:mm", "en-UK"),4,2) = _min))

var Belt2Customer1Totes =
CALCULATE(MAX(FinishingTimes[Totes]),
FILTER(FinishingTimes, FinishingTimes[Belt] = "Belt 2" &&
FinishingTimes[Customer] = "Customer 1" &&
left(format(FinishingTimes[Time], "hh:mm", "en-UK"),2) = _hour &&
mid(format(FinishingTimes[Time], "hh:mm", "en-UK"),4,2) = _min))

var Belt2Customer2Totes =
CALCULATE(MAX(FinishingTimes[Totes]),
FILTER(FinishingTimes, FinishingTimes[Belt] = "Belt 2" &&
FinishingTimes[Customer] = "Customer 2" &&
left(format(FinishingTimes[Time], "hh:mm", "en-UK"),2) = _hour &&
mid(format(FinishingTimes[Time], "hh:mm", "en-UK"),4,2) = _min))

--Compute total values
var _totesnapshot = Belt1Customer1Totes + Belt1Customer2Totes + Belt2Customer1Totes + Belt2Customer2Totes

--Calculate hours in decimal
var _hours = round(convert(divide(_totesnapshot,700,0) ,STRING),4)

--Calculate finish time
var _Finishingtime = NOW() + TIME(datediff(TIME(0,0,0), TIME(_hours,0,0), HOUR),0,0)

RETURN
_Finishingtime
 
 

Kind regards,

Rohit


Please mark this answer as the solution if it resolves your issue.
Appreciate your kudos! 😊

It worked!

 

Thank you so much!

Happy to help @billhawley . Would really appreciate your kudos ! 😊

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.