Explanation
In this example, the goal is to calculate the time remaining before an expiration date. There are many ways to do something like this in Excel, and in this article, we'll look at three different approaches:
- Calculating the remaining time in days
- Calculating the remaining time in years, months, and days
- Calculating the percentage of shelf life remaining.
Each approach includes an explanation of how the formula works.
Important notes
- Examples use the named range "cdate", which points to a cell that contains the "current date". This makes it easy to change the date used to calculate the remaining time. This also makes it possible to calculate results based on a future date. For example, you can easily change the date to the first of next month to evaluate expiration dates as of that date.
- If you prefer, you can replace the hardcoded date in cdate with the TODAY function, so that it always contains the current date. However, be aware that over time more and more items will appear as expired in this particular example.
- You should be familiar with the concept of concatenation in Excel, the process of joining values together in text strings.
How Excel Tracks Time
Excel tracks time using its date system, which is based on serial numbers. Each date is represented as a unique serial number, where January 1, 1900, is serial number 1, January 2, 1900, is serial number 2, and so on. This system allows you to perform date arithmetic easily in Excel. For example, subtracting one date from another yields the number of days between the two dates. Understanding this date system is important for creating and working with date-related formulas in Excel.
Approach 1: Calculating Time in Days
The simplest approach is to calculate the remaining time in days, which takes advantage of Excel's built-in date system and requires no special date functions. In the worksheet below, the formula in cell E5 is:
=IF(C5>cdate,C5-cdate&" days","Expired")
The logic of the formula works as follows. At a high level, the IF function controls the flow of the formula. Inside IF, the logical test is configured to check if the expiration date (C5) is greater than the current date (cdate):
=IF(C5>cdate,
Excel dates are just serial numbers underneath, so if the expiration date in C5 is larger than the "current" date (cdate) it means the date is still in the future. The logical test will return TRUE and the formula will subtract cdate from C5 and concatenate "days " to the result:
=IF(C5>cdate,C5-cdate&" days",
Otherwise, the expiration date in C5 is not larger than the current date, which means the expiration has already been reached. In that case, the logical test will return FALSE and the IF function will return "Expired" as a result.
Approach 2: Calculating Time in Years, Months, and Days
Another approach is to calculate the time remaining in years, months, and days. This requires a more elaborate formula based on the DATEDIF function. In the worksheet below, the formula in cell E5, with line breaks* added for readability, looks like this:
=IF(C5>cdate,
DATEDIF(cdate,C5,"y")&" years, "&
DATEDIF(cdate,C5,"ym")&" months, " &
DATEDIF(cdate,C5,"md")&" days",
"Expired")
Here, we calculate the time remaining before the expiration date in a combination of years, months, and days all concatenated together in a text string. The tricky part of the problem is that we need to ensure we are correctly "backing out" the time units we have already accounted for. Luckily, the DATEDIF function is designed just for this purpose.
At the top level, this formula again uses the IF function to control flow by first testing the expiration date to ensure it is still in the future. If so, we calculate a final result with three separate calls to DATEDIF. If not, we simply return "Expired":
=IF(C5>cdate,...,"Expired")
When the expiration date is greater than the current date, we call DATEDIF three times like this:
DATEDIF(cdate,C5,"y")&" years, "&
DATEDIF(cdate,C5,"ym")&" months, " &
DATEDIF(cdate,C5,"md")&" days",
- DATEDIF(cdate,C5,"y") - Calculate the number of complete years between the current date and the expiration date.
- DATEDIF(cdate,C5,"ym") - Calculate the number of complete months, ignoring the years.
- DATEDIF(cdate,C5,"md") - Calculate the number of days, ignoring the years and months.
The three results are then concatenated into a single text string, which IF returns as the final result. See this page for a more detailed example of this approach, including a simplified formula based on the LET function.
*You can add line breaks to a formula in Excel with the Keyboard Shortcut Alt + Enter.
Approach 3: Calculating Percentage of Shelf Life Remaining
In this last approach, we calculate the percentage of the shelf life that remains. Note that this requires us to have a "Packed" or "Manufactured" date to calculate the product's total shelf life. In the worksheet below, the formula in cell F5, copied down, is:
=(D5-cdate)/(D5-C5)
One key difference between this formula and the two previous formulas is that we are not using the IF function to control flow. Instead, we are simply calculating a percentage and allowing negative percentage results to pass through. The formula used in the worksheet is:
=(D5-cdate)/(D5-C5)
- (D5-cdate) - Calculate the time to expiration in days, by subtracting the current date (cdate) from the packed date (D5).
- (D5-C5) - Calculate the total shelf life in days, by subtracting packed date (C5) from the expiration date (D5).
- Divide time to expiration in days by total shelf life in days
The result is a number like 0.338 that must be then formatted as a percentage.
Creating an expiration date
To create an expiration date based on a given date you can simply add the number of days until expiration. With a date in A1:
=A1+30 // 30 days in the future
=A1+90 // 90 days in the future
Alternatively, you can use the EDATE function to calculate in months:
=EDATE(A1,1) // 1 month in the future
=EDATE(A1,3) // 3 months in the future
Both options above will work fine, but one advantage of EDATE is that it will preserve the day from the original date in A1.