Determining If a Year is a Leap Year

Written by Allen Wyatt (last updated December 12, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


7

Bob wonders if there is an easy way to determine if the year of a particular date is a leap year, for purposes of calculating interest and number of compounding days.

We all know that if a year is divisible by 4, then it is a leap year, right? Well, actually, that is wrong. So, you can't simply divide a year number by 4, as in the following, to determine if it is a leap year:

=IF(MOD(YEAR(A1), 4) = 0, "Leap", "Regular")

The formula will work for all dates within this century (years 2000 through 2099), but it won't work reliably outside that range. The reason is because "divisible by 4" is not the only test for a leap year. If the year is a century year (divisible by 100), then it is a leap year only if it is divisible by 400. So the year 2000 is a leap year, but the year 2100 is not.

If you want a bulletproof way to determine if a date occurs within a leap year, then your formula needs to be more complex:

=IF(OR(AND(MOD(YEAR(A1),4)=0,MOD(YEAR(A1),100)>0),
MOD(YEAR(A1),400)=0),"Leap","Regular")

Note that this is a single formula; it is shown here on two lines so it fits fully on the screen. The formula tests all three conditions that are necessary to determine if a date falls within a leap year.

Of course, a different approach is to simply figure out if a given year has a February 29 within it. There are any number of formulas that could be used to accomplish this task:

=IF(DAY(EOMONTH("1Jan"&YEAR(A1),1))=29, "Leap", "Regular")
=IF(MONTH(DATE(YEAR(A1),2,29))=2, "Leap", "Regular")
=IF(DAY(DATE(YEAR(A1),2,29))=29, "Leap", "Regular")
=IF(DAY(DATE(YEAR(A1),3,0))=29, "Leap", "Regular")

Any of the methods described so far work fine for any date supported by Excel, with one exception. Those that use the DATE function (the last three shown above) won't work if the date in cell A1 is in the year 1900. Those will always return that 1900 is a leap year, even though it is not. (Interestingly enough, the EOMONTH function doesn't exhibit the same problem as the DATE function does in this regard.)

If you need to work with dates that are before those supported by Excel (before January 1, 1900), then you'll need to work with years directly instead of pulling the year from an Excel date. The variation on the three-test formula will work just fine, if cell A1 contains only a year:

=IF(OR(AND(MOD(A1,4)=0,MOD(A1,100)>0),MOD(A1,400)=0),"Leap","Regular")

You could also create a user-defined function that would test the date. This approach will work just fine regardless of whether the cell contains a date value or a text value for a date. (If you enter an unsupported date value into a cell—such as 1/1/1896—then Excel treats the entry as a text value rather than trying to parse it as a date.) The following example works correctly with all dates supported by VBA, which is in the range of the year 100 through the year 9999:

Function IsLeap1(c As Range) As Boolean
    YearNo = Year(c.Value)
    If YearNo Mod 100 = 0 Then
       IsLeap1 = ((YearNo \ 100) Mod 4 = 0)
    Else
       IsLeap1 = (YearNo Mod 4 = 0)
    End If
End Function

To use the function in your worksheet you would enter a formula such as this:

=IF(IsLeap1(A1),"Leap", "Regular")

The following single-line macro works by using the trick of figuring out if there is a February 29 in the year in question:

Function IsLeap2(c As Range)
    IsLeap2 = IsDate("2/29/" & Year(c.Value))
End Function

The macro is referenced the same way in your worksheet as the previous macro:

=IF(IsLeap2(A1),"Leap", "Regular")

If you need more creative ways to determine if a date is in a leap year, check out this article:

https://chandoo.org/wp/2012/02/29/check-leap-year-using-excel/

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9978) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Dragging to Clear Cells

If you want to get rid of the contents of a range of cells, a quick way to do it is with the Fill handle. Yes, you can ...

Discover More

Printing Only Selected Rows from a Table

Tables are a great way to organize the information in a document. If your table gets quite long, you may not want to ...

Discover More

Switching between Program Windows

It is not unusual for you to work with several (and sometimes many) programs at the same time. Each program is displayed ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Calculating Weekend Dates

Do you look forward to the weekend? Well, you can use Excel to let you know when the next weekend begins. Here's how you ...

Discover More

Counting Month Ends

When working with dates in a worksheet, you may need to do some rather esoteric calculations on those dates. This tip ...

Discover More

Monthly Close-Out Dates

If your company closes out its accounting months at the end of each calendar quarter, figuring out the proper closing ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is four minus 0?

2021-03-02 08:58:33

Peter Atherton

Debra Dalgliesh has a page on leap years.
https://www.contextures.com/leapyearexcelcalcs.html
It compares a country before carrying out a calculation for julian or gregorian leapyear.


2021-01-17 06:18:07

Peter Atherton

I guess my last comment is pretty unreadable, It didn't start out like that. If anyone is interested I'll break it up.


2021-01-16 10:39:32

Peter Atherton

I had another go at this, it turned out to be more complex, some countries still use the Julian date calender while the Islamic calendar is more accurate but the year start date changes each year. The following works with Julian and Gregorian calendars. VB dateSerials number between -655974 & 2958964. A Table is used to get the year Gregorian was adopted - the links are:https://en.wikipedia.org/wiki/List_of_adoption_dates_of_the_Gregorian_calendar_per_countryhttps://en.wikipedia.org/wiki/Adoption_of_the_Gregorian_calendar#Swedenhttps://www.timeanddate.com/date/leapyear.htmlFunctions are:Option ExplicitDim myYear, myMonth As Integer, myDay As Integer, _ s As String, pos1 As Integer, pos2 As IntegerFunction MYLEAPYEAR(ByVal ref As Range, StartYear As Range) As VariantDim Calendar As String myYear = getYear(ref) If IsError(myYear) Then MYLEAPYEAR = myYear Exit Function End If If StartYear >= myYear Or StartYear.Value = 0 Then Calendar = "Julian" Else Calendar = "Gregorian" End IfSelect Case Calendar Case Is = "Julian" If myYear Mod 4 = 0 Then MYLEAPYEAR = "Leap Year" Else MYLEAPYEAR = "Not leap year" End If Case Is = "Gregorian" If myYear Mod 4 = 0 Then If myYear Mod 100 = 0 Then MYLEAPYEAR = "Non Leap" ElseIf myYear Mod 4 = 0 And _ myYear Mod 100 = 0 And myYear Mod 400 = 0 Or _ myYear Mod 4 = 0 And _ myYear Mod 100 >= 0 And myYear Mod 400 > 0 Then MYLEAPYEAR = "Leap year" End If End IfEnd SelectEnd FunctionFunction myISDATE(ByVal ref As String) As BooleanmyISDATE = False If IsDate(ref) Then myISDATE = True End IfEnd FunctionFunction getYear(ref) s = ref pos2 = InStrRev(s, "/") + 1 myYear = Mid(s, pos2, Len(s) - pos2 + 1) If myYear < 100 Or myYear > 9999 Then getYear = CVErr(xlErrNA) Exit Function End If If myISDATE(ref) Then myYear = Year(ref) ElseIf WorksheetFunction.IsNumber(ref) And Len(ref) <= 4 Then myYear = ref End If getYear = myYearEnd FunctionFunction vbDateSerial(ref As Date)vbDateSerial = refEnd FunctionFunction myDATE(ByVal ref As Long, Optional bYear = False) As Variant If IsError(ref) Then myDATE = CVErr(xlErrNA) End If If bYear Then myYear = ref 'check the year If myYear >= 10000 Or myYear < 100 Then myDATE = CVErr(xlErrNA) Exit Function End If myMonth = 1 myDay = 1 ElseIf IsNumeric(ref) Then myYear = Year(ref) myMonth = Month(ref) myDay = Day(ref) End If s = myYear & "/" & myMonth & "/" & myDay myDATE = Format(s, "DD/MM/YYYY")End FunctionFunctions in Sheet DateFormsCells Formulas in column D D3 Dropdown List D4 =IF( AND( ISNUMBER( D3), (OR( D3<100, D3 >= 10000))), NA(), IFERROR( INDEX( Countries!$B$4:$B$36, MATCH( D3, Countries!$C$4:$C$36, 0)), D3)) D5 =IF( D4 =0, 0, IF( myISDATE( D4), vbDateSerial( D4), IFERROR( vbDateSerial( "01/01/" & D4), ""))) D6 =TEXT( "01/01/" & D4, "dd/mm/yyyy") D7 Text Entry D8 Text Entry D9 =vbDateSerial( D7 ) D10 =IF( vbDateSerial( D11) < D5, "Julian", "Gregorian") D11 Text Entry D12 = MYleapyear( $D$11, $D$4) D13 =INT(( D14 / 100) -( D14) / 400)-2 D14 ="Days difference from " & IF( D10 = "Julian", "Gregorian", "Julian") Cells Formulas in column D D19 Text Entry D20 Text Entry D21 = vbDateSerial( D20) - vbDateSerial( D19 ) D22 =ROUND( D21 / 365.2425, 3) D23 =DATE(( YEAR( D21 ) - 1900 ), MONTH( D21 ), DAY( D21 )) D30 =mydate(C30) D31 =mydate(C31) D32 =mydate(C32) D33 =mydate(C33) D34 =mydate(C34) D35 =mydate(C35) D36 =mydate(C36,TRUE) D37 =mydate(C37,TRUE) [{pic}]


2020-12-15 16:11:07

J. Woolley

@Peter
Nice try, but your function needs more testing. For example, the following return TRUE:
=isLeapYear(1/15/2021)
=isLeapYear(TODAY()+31)


2020-12-14 19:41:11

Peter Atherton

If you need to use dates prior to 1900 this might help

Function isLeapYear(ByVal ref)
Dim bLeap As Boolean, myyear As Long
With WorksheetFunction
If .IsText(ref) Then
myyear = Right(ref, 4)
ElseIf .IsNumber(ref) And Len(ref) = 4 Then
myyear = ref
ElseIf IsDate(ref) Then
myyear = Year(ref)
End If

If myyear Mod 4 = 0 Then
If myyear Mod 100 = 0 And myyear Mod 400 = 0 Then
bLeap = True
ElseIf myyear Mod 100 > 0 And myyear Mod 4 = 0 Then
bLeap = True
End If
End If
End With
Result:
isLeapYear = bLeap
End Function

(see Figure 1 below)

Figure 1. 


2020-12-14 04:15:59

Willy Vanhaelen

@ Elliot
Oops my typo: "The \ operator performs an integer division: ..."


2020-12-14 04:11:00

Willy Vanhaelen

@ Elliot
It is not a typo. The / operator performs a integer division: 10 \ 3 = 3 while 10 / 3 = 3.333...


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.