Determining If a Year is a Leap Year

by Allen Wyatt
(last updated May 16, 2015)

10

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:

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

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

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

Understanding the If ... End If Structure

One of the most basic of programming structures is the conditional structure: If ... End If. This tip explains how this ...

Discover More

Nudging a Table

When laying out a page, you often need to move objects around to get them into just the right position. Word allows you to ...

Discover More

Changing Time Settings

As you no doubt know, Windows has a built-in clock that is used for a variety of purposes. This tip covers the various ways ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Date for Next Wednesday

When working with dates, it is often helpful to be able to calculate some date in the future based on a starting date. ...

Discover More

Parsing Non-Standard Date Formats

When you load data into Excel that was created in other programs, the formatting used for some types of data (such as dates) ...

Discover More

Calculating Week-Ending Dates

When working with dates, you may need to figure out all the dates on which weeks end in a given year. There are several ...

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}] 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 3 + 8?

2015-05-18 12:04:11

Michael (Micky) Avidan

@Tony Davis.
I was referring to the few last(!) COMMENTS (not in Allan's tip) whereas none of the suggestions handles the year 1900.
I, usually, don't look for "excuses" (especially not from MS).
As far as I recall, my suggested formula was the shortest among Allan's formulas that work.
Am I wrong at that point ? (Length of formula).
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
ISRAEL


2015-05-18 03:17:06

Tony Davis

Micky,
The second formula works for all years incl. 1900 wheras the other formulas are only wrong for 1900 and Microsoft explain the reasoning for that.

The article also clearly indicates that most of these formula don't work for 1900 and clearly states the "bulletproof" formula that does work for 1900.


2015-05-17 08:09:11

Michael (Micky) Avidan

@@@,
With all due respect - none of the formulas, in the suggest comments handles correctly the year 1900.
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL


2015-05-16 15:05:03

Bruce Osterberg

All this works if the year is after 1582, the year the Gregorian Calendar when put into use. Before that the Julian Calender was in use and is much simpler.


2015-05-16 11:49:52

Ron Fiorito

All the formulas provided thus far (including mine in a previous post) will tell Bob if the year is a leap year or not. However, Bob still needs to interpret the results in his other formulas to calculate interest and number of compounding days. IF the end result is simply to know how many days there are in the year (365 or 366), then the following formula gets right to the point:
=DATE(YEAR(A1)+1,1,1)-DATE(YEAR(A1),1,1)

Ron


2015-05-16 11:18:44

John Hamm

Assume the year is a leap year, and create a text string such as "2/29/2015". Use the DATEVALUE function to determine if it is a valid date:

=IF(ISERROR(DATEVALUE("2/29/"&YEAR(A1))),"Regular","Leap")


2015-05-16 11:09:55

Ron Fiorito

This formula takes a completely different approach. It uses the fact that the 60th day of the year is either in February if the year is a leap year, or March if it is not.

=MONTH(DATE(YEAR(A1),1,0)+60)-2

This formula returns a zero if it’s a leap year, or 1 if it is not. Shorter and simpler.

If you wanted a TRUE/FALSE result, just add =0 to the end like this:

=MONTH(DATE(YEAR(A1),1,0)+60)-2=0

This will return TRUE if it’s a leap year, or FALSE if it is not.

These work for all supported dates except for the buggy year 1900.

Ron


2015-05-16 10:56:18

Richard Zawadzki

The Soviet Union observed February 30 in 1930 and 1931. Sweden had Feb 30 in 1712.

If Bob was counting the number of days for interest purposes, and was working on historical dates, he'd better know the relevant country and the relevant calendar (China removed 12 days 1911/1912, Turkey removed 13 days in 1926/1927, Japan removed 12 days in 1872/1873, US Canada and UK removed 11 days in 1752)

Richard


2015-05-16 10:39:11

Richard Zawadzki

You can only have Feb 29th in a Leap Year. So, in terms of Excel checking whether a date is in a Leap Year or not, you just need to check whether Excel allows 29th Feb for that particular year. If it does allow it, then it's a Leap Year as far as Excel is concerned. The formula DATE(Year(A1), 2, 29) will display as 01-March if that year is NOT a Leap Year.
So, you can use this formula:
=IF(MONTH(DATE(YEAR(A1),2,29))=2,"Leap","Regular")

Richard Z


2015-05-16 06:47:04

Michael (Micky) Avidan

If the first THREE formulas would have been a problem for only a single year problem (1900) I would, probably, not commented BUT, although most of us will be in a better environment, the same "problem" follows the year 2100, 2200, 2300 and so on...
Therefore this must be taken into consideration – so, my contribution, to Bob's original question, was:
=(MOD(A1,4)=0)*(MOD(A1,100)<>0)+(MOD(A1,400)=0)>0
(While cell A1 holds only the year)
If pone needs to check over a full date then:
=(MOD(YEAR(A1),4)=0)*(MOD(YEAR(A1),100)<>0)+(MOD(YEAR(A1),400)=0)>0
*** Returning TRUE for a Leap year and FALSE for a Regular year.
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL


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.