Summary

To get a fiscal year from a date, you can use a formula based on the YEAR and MONTH functions. In the example shown, the formula in D5 is:

=YEAR(B5)+(MONTH(B5)>=C5)

The result in column D is the fiscal year for each date, based on a fiscal year start in July.

Generic formula

=YEAR(date)+(MONTH(date)>=startmonth)

Explanation 

In this example, the goal is to return the fiscal year for any given date, where a fiscal year starts in July as seen in the worksheet. By convention a fiscal year is denoted by the year in which it ends. So, if a fiscal year begins in July, then the date August 1, 2018 is in fiscal year 2019. The formula in D5, copied down, is:

=YEAR(B5)+(MONTH(B5)>=C5)

On the left, the YEAR function first returns the year from the date in B5:

=YEAR(B5) // returns 2017

To adjust this value to return the fiscal year for a July start, the following boolean expression is added to the year value:

+(MONTH(B5)>=C5) // returns zero

Here, the MONTH function returns the month from the date in B5 (1), and this result is compared to the start month in C5 (7). Since 1 is less than 7, the expression returns FALSE, which is evaluated by Excel as zero (0). The zero has no effect, so the final result is 2017. In cases where the month number for a date is greater than 7, this expression will return TRUE, which will be evaluated as 1 by Excel. This increments the year by one.

Note: with boolean logic, TRUE values are evaluated as 1 and FALSE values are evaluated as zero. Therefore, if the month from the date is greater than or equal to the start month, the expression returns TRUE, or 1. If not, the expression returns FALSE, or zero.

Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.