Multiple If True Values - IF Function Excel

hue

New Member
Joined
Jun 23, 2011
Messages
4
Not an expert so I need allot of help. In a production schedule I have various models to make with X number of units per model in a day. Using VLOOKUP I have a time value (production time) column for each model multiplied by its number of units, so I know the time it takes to produce each individual model in a day. I now need to include a PST (Production Standard Time) column for each model so workers can know at what time they should finish each of the models in the daily schedule. During our work hours (7:00am - 5:06pm) I have 3 lunch/rest breaks one @ 9:20 am(lasts 19min), 12:30 pm(lasts 29min) and 3:00 pm(lasts 9min) so I need to add to the PST that specific lunch/rest time if a model is finished during any of the lunch/rest periods, so I’ll assure the PST is accurate. How can achieve this using one single formula, considering the 3 criteria?

Criteria #1: IF((A1+B1)>=timevalue("9:20 am") but <=timevalue("12:30 pm"), (A1+B1)+time(0,19,0), (A1+B1))
Criteria #2: IF((A1+B1)>=timevalue("12:30 pm") but <=timevalue("3:00 pm"), (A1+B1)+time(0,29,0), (A1+B1))
Criteria #3: IF((A1+B1)>=timevalue("3:00 pm"), (A1+B1)+time(0,9,0), (A1+B1))

Since the values will be adding up as the day goes, it can occur, that the value (A1+B1) falls directly into the second criteria (eg. 1:37 pm), I need then for it to add the 29 minutes plus the 19 of the first criteria, and so on and so forth. Thanks so much in advance.
 

Excel Facts

What is the last column in Excel?
Excel columns run from A to Z, AA to AZ, AAA to XFD. The last column is XFD.
Actually, what you want is something slightly different than what you have stated.

For the 2nd break you don't want to check if A1+B1>12:30 but if A1+B1+1st break > 12:30! The same concept applies to the 3rd break.

Here's what you should use
=A1+B1+IF(SUM(A1:B1)>=TIMEVALUE("9:20:00"),TIME(0,19,0),0)+IF(SUM(A1:B1)>=TIMEVALUE("12:30:00")-TIME(0,19,0),TIME(0,29,0),0)+IF(SUM(A1:B1)>=TIMEVALUE("15:00:00")-TIME(0,19,0)-TIME(0,29,0),TIME(0,9,0),0)

Not an expert so I need allot of help. In a production schedule I have various models to make with X number of units per model in a day. Using VLOOKUP I have a time value (production time) column for each model multiplied by its number of units, so I know the time it takes to produce each individual model in a day. I now need to include a PST (Production Standard Time) column for each model so workers can know at what time they should finish each of the models in the daily schedule. During our work hours (7:00am - 5:06pm) I have 3 lunch/rest breaks one @ 9:20 am(lasts 19min), 12:30 pm(lasts 29min) and 3:00 pm(lasts 9min) so I need to add to the PST that specific lunch/rest time if a model is finished during any of the lunch/rest periods, so I’ll assure the PST is accurate. How can achieve this using one single formula, considering the 3 criteria?

Criteria #1: IF((A1+B1)>=timevalue("9:20 am") but <=timevalue("12:30 pm"), (A1+B1)+time(0,19,0), (A1+B1))
Criteria #2: IF((A1+B1)>=timevalue("12:30 pm") but <=timevalue("3:00 pm"), (A1+B1)+time(0,29,0), (A1+B1))
Criteria #3: IF((A1+B1)>=timevalue("3:00 pm"), (A1+B1)+time(0,9,0), (A1+B1))

Since the values will be adding up as the day goes, it can occur, that the value (A1+B1) falls directly into the second criteria (eg. 1:37 pm), I need then for it to add the 29 minutes plus the 19 of the first criteria, and so on and so forth. Thanks so much in advance.
 
Upvote 0
Dear tusharm,

I apreciate your time and efforts to help with this issue. I inform you that it seems to work but at a certain point it just doesn't, hope with this image/example I can explain the situation:

6XZa8jyY_IEno6eC9xjcZ8tZ5bgznTIVX44CV8BiFqM


Hue
 
Upvote 0
What you are doing is different from what you described! Consequently, I suspect that the way you adapted the formula for your specific scenario, you are double-counting all breaks starting with row 5.

Start with G2: Wherever I used A1+B1, or SUM(A1:B1) -- and which you adjusted appropriately, replace those terms with TIME(7,0,0)+SUM($D$2:$D2) -- note there is 1 $ missing!.

Better yet, put the start time in some cell and replace all references to TIME(7,0,0) with an absolute reference to that cell.

Now, copy G2 as far down column G as needed.


Dear tusharm,

I apreciate your time and efforts to help with this issue. I inform you that it seems to work but at a certain point it just doesn't, hope with this image/example I can explain the situation:

6XZa8jyY_IEno6eC9xjcZ8tZ5bgznTIVX44CV8BiFqM



Hue
 
Upvote 0
tusharm,

You are the best! it worked! to perfection. I really appreciate your expertise, time and effort on this issue, it will will help me super. I give you the formula as it was finalized and according to me at it's minimal expression:

=TIME(7,,)+SUM($I$6:I6)
+IF(TIME(7,,)+SUM($I$6:I6)>=TIME(9,20,),TIME(,19,),)
+IF(TIME(7,,)+SUM($I$6:I6)>=TIME(12,30,)-TIME(,19,),TIME(,29,),)
+IF(TIME(7,,)+SUM($I$6:I6)>=TIME(15,,)-TIME(,19,)-TIME(,29,),TIME(,9,),)

Hue
 
Upvote 0
tusharm,

Hi, hope you are fine, I have a couple of questions, if you have time, I'll apreciate it if you can look at the image and offer a coment:

0YOoAKjQw-zo2Bkk6BBdazwxJV60cnuJIgNf-NqxiUo


Hue
 
Upvote 0

Forum statistics

Threads
1,221,310
Messages
6,159,173
Members
451,543
Latest member
cesymcox

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top