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.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
It is not uncommon to reuse formulas in a variety of workbooks. If you develop some "gotta keep" formulas, here are some ...
Discover MoreIf you have a mixture of numbers and letters in a cell, you may be looking for a way to access and use the numeric ...
Discover MorePostal codes in Canada consist of six characters, separated into two groups. This tip explains the format and then shows ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-10-25 23:44:00
Jess
I should note that on my previous comment it will show the date as Nov. 4th, 2020.
If you want the full month, replace "mmm" with "mmmm" and remove the periods (easy enough with find and replace)
2020-10-25 23:40:40
Jess
Hi! I came up with a different solution to this issue and I wanted to share it. I was making a planner spreadsheet where in one cell I had the date, with custom number formatting=dddd so it would only show the name of the weekday. Then I had a formula referencing that cell: =IF(OR(DAY(A1)=1,DAY(A1)=21,DAY(A1)=31),TEXT(A1,"mmm")&". "&DAY(A1)&"st, "&YEAR(A1),IF(OR(DAY(A1)=2,DAY(A1)=22),TEXT(A1,"mmm")&". "&DAY(A1)&"nd, "&YEAR(A1),IF(OR(DAY(A1)=3,DAY(A1)=23),TEXT(A1,"mmm")&". "&DAY(A1)&"rd, "&YEAR(A1),TEXT(A1,"mmm")&". "&DAY(A1)&"th, "&YEAR(A1))))
It's always nice to have many ways to do something. I hope this helps someone.
2020-09-04 03:48:23
Stordarth
I did it by using the 4 custom formats and applying conditional formatting using formulas.
My format structure is:
ddd, d"x" mmmm yyyy
"x" is one of the four ordinals, ddd shows the 3 letter abbreviated day, d returns the DAY value, mmmm returns the full month name, and yyyy the full year.
I then used four conditional formatting rules on my desired range:
=IF(OR(DAY(B3)=1,DAY(B3)=21,DAY(B3)=31),TRUE,FALSE) for the "st" days
=IF(OR(DAY(B3)=2,DAY(B3)=22),TRUE,FALSE) for the "nd" days
=IF(OR(DAY(B3)=3,DAY(B3)=23),TRUE,FALSE) for the "rd" days
=IF(OR(AND(DAY('Raw Data'!B3)>3,DAY('Raw Data'!B3)<21),AND(DAY('Raw Data'!B3)>23,DAY('Raw Data'!B3)<31)),TRUE,FALSE) for the "th" days
Substitute B3 for the cell you're applying the formatting to, and it will adjust itself across your range.
Tested for all 31 day values and it works perfectly.
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?
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 © 2021 Sharon Parq Associates, Inc.
Comments