Checking for leap year

sylvest

New Member
Joined
Sep 15, 2006
Messages
46
A year that is a multiple of 4 is a leap year. However, it was also concluded that a year that is a multiple of 100 should not be a leap year, unless it is also a multiple of 400. - Any problem with the below code?

If ((Range("Score").Value Mod 4 = 0) And (Range("Score").Value Mod 100 <> 0)) Or _
((Range("Score").Value Mod 100 = 0) And (Range("Score").Value Mod 400 <> 0)) Then

MsgBox Range("Score").Value & " is a leap year."
Else
MsgBox Range("Score").Value & " is not a leap year."
End If
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.

Domski

Well-known Member
Joined
Jan 18, 2005
Messages
7,292
I've used this formula to test for leap years before, probably not the best way but I think it works.

=IF(DAY(EOMONTH(DATE(A1,2,1),0))=29,"Yes","No")

Where the year is entered in A1.

Can probably be manipulated for code.
 

xapie128

Board Regular
Joined
Aug 26, 2006
Messages
82
Any problem with the below code?

If ((Range("Score").Value Mod 4 = 0) And (Range("Score").Value Mod 100 <> 0)) Or _
((Range("Score").Value Mod 100 = 0) And (Range("Score").Value Mod 400 <> 0)) Then

MsgBox Range("Score").Value & " is a leap year."
Else
MsgBox Range("Score").Value & " is not a leap year."
End If
Yes, there's a problem with it for years that end with "00". For instance, it says that 1900 was a leap year (it wasn't) and that 2000 wasn't a leap year (it was). You can fix it this way:

Code:
If ((Range("Score").Value Mod 4 = 0) And (Range("Score").Value Mod 100 <> 0)) Or _
(Range("Score").Value Mod 400 = 0) Then

Domski's idea is good, but Microsoft's algorithm seems to have a problem with 1700, stating that it was a leap year (it wasn't) and that 1600 was not a leap year (it was).

Note that the Gregorian calendar began on Friday, October 15th, 1582. Dates prior to that are invalid with any of these formulas.
 

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825
Assuming you only want to check years after 1900 you could just use

=DAY(DATE(A1,3,0))=29
 

Norie

Well-known Member
Joined
Apr 28, 2004
Messages
76,300
Office Version
  1. 365
Platform
  1. Windows
In VBA try this.
Code:
If Day(DateSerial(Range("Score").Value, 3, 0)) = 29 Then
     MsgBox Range("Score").Value & " is a leap year."
Else
     MsgBox Range("Score").Value & " is not a leap year."
End If
 

Forum statistics

Threads
1,137,341
Messages
5,680,922
Members
419,945
Latest member
Carrie Sellers

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top