Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Adding Ordinal Notation to Dates.

Adding Ordinal Notation to Dates

by Allen Wyatt
(last updated April 30, 2020)

4

When developing a workbook, you may have a need to place suffixes such as "st, nd, rd, or th" at the end of dates, as in "9th March." Unfortunately, there is no way to do this using the built-in date formats you can apply to individual cells. You can create custom formats for each of the four suffix types, if desired, but they would have to be applied individually based on the contents of the cell itself.

The only other option is to use some sort of conversion formula. These are easy enough to put together, but the resulting cell will not contain a true Excel date, but text. This precludes the cell contents from being used in other date-related functions. The following is an example of the type of conversion formula you can use:

=DAY(A1)&IF(OR(DAY(A1)={1,2,3,21,22,23,31}),
CHOOSE(1*RIGHT(DAY(A1),1),"st","nd ","rd "),"th")
&TEXT(A1,"mmmm, yyyy")

There are others, but they all essentially do the same thing—pull the various parts of a date apart and put them back together with the proper suffix.

If you prefer, you can also create a macro function that would return a properly formatted date, with the ordinal suffix. The following is one such macro:

Function OrdinalDate(myDate As Date)
    Dim dDate As Integer
    Dim dText As String
    Dim mDate As Integer
    Dim mmmText As String

    dDate = Day(myDate)
    mDate = Month(myDate)

    Select Case dDate
        Case 1: dText = "st"
        Case 2: dText = "nd"
        Case 3: dText = "rd"
        Case 21: dText = "st"
        Case 22: dText = "nd"
        Case 23: dText = "rd"
        Case 31: dText = "st"
        Case Else: dText = "th"
    End Select

    Select Case mDate
        Case 1: mmmText = " January"
        Case 2: mmmText = " February"
        Case 3: mmmText = " March"
        Case 4: mmmText = " April"
        Case 5: mmmText = " May"
        Case 6: mmmText = " June"
        Case 7: mmmText = " July"
        Case 8: mmmText = " August"
        Case 9: mmmText = " September"
        Case 10: mmmText = " October"
        Case 11: mmmText = " November"
        Case 12: mmmText = " December"
    End Select

    OrdinalDate = dDate & dText & mmmText
End Function

You use the macro by simply invoking it within a cell formula. For example, if you have a date stored in cell B7, you can use the following in any other cell:

=OrdinalDate(B7)

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 (2510) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Adding Ordinal Notation to Dates.

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

Workbook, Once Created, is Too Big for Memory

Understanding how Excel uses memory, how much it allows, and how to work around the limitations.

Discover More

Moving a Worksheet to Another Workbook

One of the organizational tools provided by Excel is the ability to move worksheets from one workbook to another. Here's ...

Discover More

Limiting Where a Workbook is Used

Want to limit who can use your workbook and on what system? Locking down a workbook can be trickier than you might imagine.

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 (menu)

Totaling Across Worksheets

Want to sum the values in the same cell on a range of worksheets? It's not as easy as summing a range on the same ...

Discover More

Splitting Cells by Case

Excel provides several different ways that you can split apart the contents of a cell. One way it doesn't provide is to ...

Discover More

Averaging a Non-Contiguous Range

Figuring out how to average data that is in a contiguous range of cells is easy. When the data is spread over a group of ...

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 6 - 0?

2019-10-19 11:40:37

Willy Vanhaelen

Oops ! disregard the 2 previous UDF's. I have been a little hasty and didn't test them enough. Here is one that does the job correctly (still as short):

Function OrdinalDate(D As Date)
Dim Ord As String
Select Case Day(D)
Case 1, 21, 31: Ord = "st "
Case 2, 22: Ord = "nd "
Case 3, 23: Ord = "rd "
Case Else: Ord = "th "
End Select
OrdinalDate = Day(D) & Ord & Format(D, "mmmm")
End Function


2019-10-19 08:44:17

Willy Vanhaelen

Here is an even shorter version:

Function OrdinalDate(D As Date)
Dim Ord As String
Ord = "th "
On Error Resume Next
Ord = Choose(Right(Day(D), 1), "st ", "nd ", "rd ")
OrdinalDate = Day(D) & Ord & Format(D, "mmmm")
End Function


2019-10-19 08:27:58

Willy Vanhaelen

The macro in this tip can be drastically shortened. Here is my simplified version:

Function OrdinalDate(D As Date)
Dim Ord As String
Select Case Right(Day(D), 1)
Case 1: Ord = "st "
Case 2: Ord = "nd "
Case 3: Ord = "rd "
Case Else: Ord = "th "
End Select
OrdinalDate = Day(D) & Ord & Format(D, "mmmm")
End Function


2017-02-24 09:11:22

Ell

This gives the American date version, how do I change this to the other way around?


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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.