Raymond's work requires that he format dates so they show in what he believes is a rather odd format. If, for instance, a cell contains a date of 10/20/19, he needs it to display as "SU 10/20", without the quotes. (SU is a two-character representation of the day of the week, in this case Sunday.) Raymond wonders if there is a way to do this as, perhaps, a custom format.
There is no way to do this exactly using a custom format. The reason is that there is no code in custom formats that allow you to create a two-character day of the week. The closest that could be done in a custom format is for a three-character day of the week:
ddd m/d
Even that, though, is a bit off because it won't do the three-character day of the week in uppercase.
So, that leads us to using a formula to come up with the formatted date. If you have the date in cell A1, you could use the following formula:
=LEFT(UPPER(TEXT(A1,"ddd")), 2) & " " & TEXT(A1,"m/d")
This uses the TEXT function to return, first, the three-character day of the week which is converted to uppercase using the UPPER formula. The LEFT function is then used to grab the first two characters of that weekday which is then added to the month/day combination. This returns exactly what Raymond wanted.
The downside to using this approach is that the date returned by the formula is text; it is not an actual date. If we had been able to use a custom format, the underlying date value would have been unchanged. This, though, would be the case for any odd date formatting like this. Because of this potential downside, you may want to retain the actual dates as dates, even if it is in a hidden column or a hidden worksheet.
You could also, if desired, create a macro that would return a string with the formatted date. Here's a simple user-defined function:
Function FmtDate(d As Date) As String Dim s As String s = UCase(Left(WeekdayName(Weekday(d)), 2)) s = s & " " & Format(d, "m/d") FmtDate = s End Sub
You can then use the function in the following way in your worksheet:
=FmtDate(A1)
This assumes the date is in A1, and the function returns a date string formatted as Raymond desires.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13704) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365.
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!
Need to copy a range of dates and update them to a different year? Here are a number of ways to accomplish this task with ...
Discover MoreIt is no secret that Excel allows you to work with dates in your worksheets. Getting your information into a format that ...
Discover MoreCalculating an age is a common task when working with dates. If you want to figure out the number of years and months ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-11-25 16:53:45
Yvan Loranger
How about =choose(weekday(a1),"SU","MO","TU","WE","TH","FR","SA")&" "&month(a1)&"/"&day(a1)
2019-11-23 08:05:09
Willy Vanhaelen
@Joe: elegant solution!
For who prefers to work with the UDF, here is a one-liner version :
Function FmtDate(d As Date) As String
FmtDate=UCase(Left(WeekdayName(Weekday(d)),2))&" "&Format(d,"mm/dd")
End Function
It ends with a End Function istead of End Sub in this tip which of cource causes an error. This also proves that the function was not even tested.
2019-11-23 06:36:42
Joe
You can use several conditional formatting rules to achieve this and still keep the cell value as a date. Set up 7 conditional formatting formulae
'=WEEKDAY(A1,2)=1' through to '=WEEKDAY(A1,2)=7'
and set a custom number format for each to
'"Mo " dd/mm' through to '"Su " dd/mm' (or '"Mo " mm/dd' etc for American style dates).
Apply this to all relevant cells and the cells stay as dates, but display as required.
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.
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