Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Rounding to the Nearest Quarter Hour.
Written by Allen Wyatt (last updated October 26, 2019)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Lisa is trying to set up a timesheet. It needs to go by the seven-minute rule. If it is 7 minutes till the hour it rounds to, say, 8:00 am; if it is 10 till it rounds to 7:45. If it is 7 minutes after it would be 8:00, and 8 minutes after would be 8:15 am. In other words, whatever time is entered needs to be rounded to the nearest quarter hour.
The full name of the rule that Lisa mentions is the "7/8-minute rule." It's a throwback to when timecards were processed manually. Depending on the particular time clock, the rule may not have the same result as quarter-hour rounding. Consider that the 7/8-rule rounds down all the way to 7 minutes and 59.9 seconds whereas quarter-hour rounding rounds down only to 7 minutes and 29.9 seconds. It's not a huge difference, but the 7/8-minute rule in a payroll context gives employers a 30 second freebie.
If Lisa is only entering hours and minutes, then quarter-hour rounding is just fine. This can be handled in a number of different ways. For instance, you could create a lookup table that shows what the rounded time would be for each time within the hour, and then—based on the number of minutes in the original time—use VLOOKUP (or one of the other lookup functions) to determine the correct minutes.
A better way, however, is to remember that Excel stores times as a fraction of a day, so to convert any given time to minutes you simply multiply a time value by the number of minutes in a day (24 * 60 = 1440). You can then divide by the desired time interval, in this case 15. This means that you can use any of the following equivalent formulas, if the time you want to round is in cell A1:
=ROUND(A1*(24*60/15),0)/(24*60/15) =ROUND(A1*(1440/15),0)/(1440/15) =ROUND(A1*96,0)/96
If you prefer, you can also "reverse" the formula by using any of these equivalent formulas:
=ROUND(A1/(15/(24*60)),0)*(15/(24*60)) =ROUND(A1/(15/1440),0)*(15/1440) =ROUND(A1/0.01041667,0)*0.01041667
If you have the Analysis ToolPak enabled on your system, you could also use the MROUND function to determine the rounded time. The following are equivalent formulas that use the MROUND function:
=MROUND(A1,15/60/24) =MROUND(A1,0.25/24) =MROUND(A1,0.01041667)
If you are not comfortable figuring out the number that Excel uses to represent 15 minutes (as is done in these formulas), you could combine MROUND with the TIME function, in this manner:
=MROUND(A1,TIME(0,15,0))
As mentioned, all the formulas presented so far assume that seconds are not being entered into the original value. If they are being entered and you want to use the 7/8 rule exactly (favoring the employer for that half minute), then you need to use an adapted formula, in this manner:
=ROUND((A1*1440-0.5)/15,0)*(15/1440)
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9360) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Rounding to the Nearest Quarter Hour.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
When working with dates and the relationship between dates, Excel provides a variety of worksheet functions that may ...
Discover MoreExcel can easily store dates. If you want to increment a date by one month, there are a number of ways you can accomplish ...
Discover MoreWant to add an ordinal suffix to a number, as in 2nd, 3rd, or 4th? Excel doesn't provide a way to do it automatically, ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments