Round toTime to Quarter of the Hour

cityanangelstx2004

Board Regular
Joined
Jun 18, 2004
Messages
56
Hello. I am trying to use the following formula to round up to the quarter of the hour. I would prefer that when the total time is 2:11 that the cell will round up to 2:15 and the cell is formated to convert 2:15 to 2.25. I hope this makes sense. If the time is 2:06 then the cell is converted to 2.00.

'Time is calculated in this cell based on cells c13:f13.
r13 =(C13>D13)+D13-C13+(E13>F13)+F13-E13

'This cell is supposed to round up to the closest quarter of the hour.
t13=ROUND(R13*24/0.25,2)*((0.25/24)*24)

At first i seem to get it to work but then it doesn't. :rolleyes: Anyone's help is appreciated. Thank you.
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Ok, I'm not sure if this is the best way to handle it, but it seems to work for my testing. Note, I had to round each time entry and then total at the end for it to work.
test_RoundTime.xls
CDEFGHIJKLMN
11MROUND
12INOUTINOUTInOutInOutTotal
138:00 AM12:00 PM1:00 PM5:00 PM8.0012.0013.0017.008.00
148:10 AM12:00 PM1:00 PM5:00 PM8.0012.0013.0017.008.00
158:11 AM12:00 PM1:00 PM5:00 PM8.2512.0013.0017.007.75
168:06 AM12:00 PM1:00 PM5:00 PM8.0012.0013.0017.008.00
178:00 AM12:00 PM1:00 PM5:00 PM8.0012.0013.0017.008.00
188:00 AM12:06 PM1:00 PM5:00 PM8.0012.0013.0017.008.00
198:00 AM12:12 PM1:00 PM5:00 PM8.0012.2513.0017.008.25
208:00 AM12:14 PM1:00 PM5:00 PM8.0012.2513.0017.008.25
218:00 AM12:00 PM1:00 PM5:00 PM8.0012.0013.0017.008.00
228:00 AM12:00 PM1:06 PM5:00 PM8.0012.0013.0017.008.00
238:00 AM12:00 PM1:10 PM5:00 PM8.0012.0013.0017.008.00
248:00 AM12:00 PM1:11 PM5:00 PM8.0012.0013.2517.007.75
Sheet1
 
Upvote 0
I just realized this doesn't solve ALL your problems. I didn't account for the other quarter hours. Maybe it would be better if we used a vlookup table.
 
Upvote 0
Ok, here's how you would do it as a VLOOKUP.
test_RoundTime.xls
OPQR
12VLOOKUP
138:00 AM8:00 AM
148:11 AM8:15 AM
158:15 AM8:15 AM
168:26 AM8:30 AM
178:30 AM8:30 AM
188:41 AM8:45 AM
198:45 AM8:45 AM
208:56 AM9:00 AM
Sheet1


I setup a range like this going all the way up to 5:00 PM and named it myLookup. Then in the formulas I have:
test_RoundTime.xls
CDEFGHIJKLM
12INOUTINOUTInOutInOutTotal
138:00 AM12:00 PM1:00 PM5:00 PM8:00 AM12:00 PM1:00 PM5:00 PM8:00
148:10 AM12:00 PM1:00 PM5:00 PM8:00 AM12:00 PM1:00 PM5:00 PM8:00
158:11 AM12:00 PM1:00 PM5:00 PM8:15 AM12:00 PM1:00 PM5:00 PM7:45
168:14 AM12:00 PM1:00 PM5:00 PM8:15 AM12:00 PM1:00 PM5:00 PM7:45
178:00 AM12:00 PM1:00 PM5:00 PM8:00 AM12:00 PM1:00 PM5:00 PM8:00
188:00 AM12:41 PM1:00 PM5:00 PM8:00 AM12:45 PM1:00 PM5:00 PM8:45
198:00 AM12:40 PM1:00 PM5:00 PM8:00 AM12:30 PM1:00 PM5:00 PM8:30
208:00 AM12:00 PM1:00 PM5:00 PM8:00 AM12:00 PM1:00 PM5:00 PM8:00
Sheet1
 
Upvote 0
If you always want to round up to 15 minutes, try this in T13:

=CEILING(R13,TIME(0,15,0))

Fill down

Denis
 
Upvote 0
This rounds down or up to the nearest 15 minutes:

Code:
=IF(MOD(R13,TIME(0,15,0))<TIME(0,8,0),R13-MOD(R13,TIME(0,15,0)),CEILING(R13,TIME(0,15,0)))

Denis
 
Upvote 0

Forum statistics

Threads
1,214,830
Messages
6,121,839
Members
449,051
Latest member
excelquestion515

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