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.
Written by Allen Wyatt (last updated March 4, 2023)
This tip applies to Excel 97, 2000, 2002, and 2003
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:
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.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
If you need to generate a random sequence of characters, of a fixed length, then you'll appreciate the discussion in this ...
Discover MoreNeed to figure out if a value is outside of some arbitrary limit related to a different value? There are a number of ways ...
Discover MoreWant to know how to move pieces of information contained in one cell into individual cells? This option exists in using ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments