Rename sheet from ddMMMyyyy (alphanumeric) to yyyymmdd (numeric only)

Dr. Demento

Well-known Member
Joined
Nov 2, 2010
Messages
618
Office Version
  1. 2019
  2. 2016
Platform
  1. Windows
I've got a large number of worksheets that are named as ddMMMyyyy (ie, 02Jan2012) that I would like to name to a numeric only format (yyyymmdd: 20120102). Additionally, since some sheets are not named as a date, I would like to test them first (something akin to ISDATE) but I keep coming up short. Any ideas for a function??

Thanks y'all.
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
How about:
Code:
Sub datechanger()
For Each current In Worksheets
If IsNumeric(Right(current.Name, 4)) Then
current.Name = Application.Text(current.Name, "YYYYMMDD")
End If
Next
End Sub
 
Upvote 0
I've got a large number of worksheets that are named as ddMMMyyyy (ie, 02Jan2012) that I would like to name to a numeric only format (yyyymmdd: 20120102). Additionally, since some sheets are not named as a date, I would like to test them first (something akin to ISDATE) but I keep coming up short. Any ideas for a function??
Use the structure of this line of code to create the new name for your worksheets...

NewSheetName = Format(Format(OldSheetName, "@@-@@@-@@@@"), "yyyymmdd")
 
Upvote 0
@Rick - I never in a million years would have thought of that. Thank you!!

@Roderick - nice call on the test! Can't seem to think outside the box today. Thanks!!
 
Upvote 0
Rick,

Is there any way to test if a sheet has already been renamed to the desired format (yyyymmdd) so that if the sub is re-run, it won't rename any properly named sheets??

Thanks much.
 
Upvote 0
Rick,

Is there any way to test if a sheet has already been renamed to the desired format (yyyymmdd) so that if the sub is re-run, it won't rename any properly named sheets??
Use this code structure instead...
Code:
[table="width: 500"]
[tr]
	[td]If OldSheetName Like "##[A-Za-z][A-Za-z][A-Za-z]####" Then
  NewSheetName = Format(Format(OldSheetName, "@@-@@@-@@@@"), "yyyymmdd")
End If[/td]
[/tr]
[/table]
 
Last edited:
Upvote 0
Like Roderick's approach, I was able to use the following code to eliminate those sheets that had already been renamed, but I was hoping for something for specific to the date format.

Code:
    If IsNumeric(Right(sht.name, 4)) And _
      IsNumeric(sht.name) = False Then _
      sht.name = Format(Format(sht.name, "@@-@@@-@@@@"), "yyyymmdd")
 
Upvote 0
Nevermind; I figured it out :-)

Code:
If IsDate(DateSerial(Left(sht.name, 4), Mid(sht.name, 5, 2), Right(sht.name, 2))) = False Then

except now I don't know how to run error trapping other than the dreaded On Error Resume Next. Oh well, one thing at a time.

Thanks everyone!!

EDIT: Sorry, Rick. Despite multiple Reloads, the webpage didn't show your response until now. Much more specific/elegant than mine!
 
Last edited:
Upvote 0
Like Roderick's approach, I was able to use the following code to eliminate those sheets that had already been renamed, but I was hoping for something for specific to the date format.

Code:
    If [B][COLOR="#FF0000"]IsNumeric[/COLOR][/B](Right(sht.name, 4)) And _
      [B][COLOR="#FF0000"]IsNumeric[/COLOR][/B](sht.name) = False Then _
      sht.name = Format(Format(sht.name, "@@-@@@-@@@@"), "yyyymmdd")
While I do not expect your sheet names to be such as to cause a problem, I thought you might find this previous post of mine about the IsNumeric function to be of interest (it should explain why I posted the code that I did in Message #6)...

I usually try and steer people away from using IsNumeric to "proof" supposedly numeric text. Consider this (also see note below):

Rich (BB code):
ReturnValue = IsNumeric("($1,23,,3.4,,,5,,E67$)")

Most people would not expect THAT to return True. IsNumeric has some "flaws" in what it considers a proper number and what most programmers are looking for.

I had a short tip published by Pinnacle Publishing in their Visual Basic Developer magazine that covered some of these flaws. Originally, the tip was free to view but is now viewable only by subscribers.. Basically, it said that IsNumeric returned True for things like -- currency symbols being located in front or in back of the number as shown in my example (also applies to plus, minus and blanks too); numbers surrounded by parentheses as shown in my example (some people use these to mark negative numbers); numbers containing any number of commas before a decimal point as shown in my example; numbers in scientific notation (a number followed by an upper or lower case "D" or "E", followed by a number equal to or less than 307 -- the maximum power of 10 in VB); and Octal/Hexadecimal numbers (&H for Hexadecimal, &O or just & in front of the number for Octal).

NOTE:
======
In the above example and in the referenced tip, I refer to $ signs and commas and dots -- these were meant to refer to your currency, thousands separator and decimal point symbols as defined in your local settings -- substitute your local regional symbols for these if appropriate.

As for your question about checking numbers, here are two functions that I have posted in the past for similar questions..... one is for digits only and the other is for "regular" numbers (the code is simple enough that it can be pulled from the function "housing" and used directly inside your own code):

Rich (BB code):
Function IsDigitsOnly(Value As String) As Boolean
    IsDigitsOnly = Len(Value) > 0 And Not Value Like "*[!0-9]*"
End Function

Function IsNumber(ByVal Value As String) As Boolean
    '   Leave the next statement out if you don't
    '   want to provide for plus/minus signs
    If Value Like "[+-]*" Then Value = Mid$(Value, 2)
    IsNumber = Not Value Like "*[!0-9.]*" And Not Value Like "*.*.*" And Len(Value) > 0 And Value <> "."
End Function

Here are revisions to the above functions that deal with the local settings for decimal points (and thousand's separators) that are different than used in the US (this code works in the US too, of course).

Rich (BB code):
Function IsNumber(ByVal Value As String) As Boolean
  Dim DP As String
  '   Get local setting for decimal point
  DP = Format$(0, ".")
  '   Leave the next statement out if you don't
  '   want to provide for plus/minus signs
  If Value Like "[+-]*" Then Value = Mid$(Value, 2)
  IsNumber = Not Value Like "*[!0-9" & DP & "]*" And Not Value Like "*" & _
             DP & "*" & DP & "*" And Len(Value) > 0 And Value <> DP
End Function

I'm not as concerned by the rejection of entries that include one or more thousand's separators, but we can handle this if we don't insist on the thousand's separator being located in the correct positions (in other words, we'll allow the user to include them for their own purposes... we'll just tolerate their presence).

Rich (BB code):
Function IsNumber(ByVal Value As String) As Boolean
  Dim DP As String
  Dim TS As String
  '   Get local setting for decimal point
  DP = Format$(0, ".")
  '   Get local setting for thousand's separator
  '   and eliminate them. Remove the next two lines
  '   if you don't want your users being able to
  '   type in the thousands separator at all.
  TS = Mid$(Format$(1000, "#,###"), 2, 1)
  Value = Replace$(Value, TS, "")
  '   Leave the next statement out if you don't
  '   want to provide for plus/minus signs
  If Value Like "[+-]*" Then Value = Mid$(Value, 2)
  IsNumber = Not Value Like "*[!0-9" & DP & "]*" And Not Value Like "*" & _
             DP & "*" & DP & "*" And Len(Value) > 0 And Value <> DP
End Function

Closing Note
-----------------------------
The above functions for checking if text is a number were written back in my volunteer days for the compiled version of Visual Basic and while it all still works in Excel's VBA, you could also reach out to the worksheet's ISNUMBER function and test the text for being a number that way (its probably a tad slower to do it that way, but probably not enough to worry about unless used in a huge loop of some kind).

Rich (BB code):
Function IsNumber(Value) As Boolean
  IsNumber = Evaluate("ISNUMBER(0+""" & Value & """)")
End Function
 
Upvote 0
Just for posterity... this version ignore if format is already correct (for re-running)

Sub datechanger()
For Each current In Worksheets
on error resume next
If IsNumeric(Right(current.Name, 4)) Then
current.Name = Application.Text(current.Name, "YYYYMMDD")
End If
resume next
Next
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,236
Messages
6,170,917
Members
452,366
Latest member
TePunaBloke

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
Back
Top