×

The Fastest Way To Convert Numbers Stored As Text To Numbers & Dates

By Chris Newman •  Updated: 08/21/14 •  8 min read
Get Rid of Numbers Stored As Text Error in Microsoft Excel

What This VBA Code Does

I have always hated the time it takes to convert text to numbers, especially on large database exports.  That’s why I was ecstatic to find a VBA solution that speeds up text conversion from minutes to just a few seconds.  The solution was written by Ejaz Ahmed of Struggling to Excel.  He was gracious enough to allow me to share his code with you all and I really think you will be blown away by its capabilities.

Ejaz’s code does much more than just convert text to numerical values.  It also trims the selected data (deleting any trailing or preceding spaces in your values) and converts text to dates.  The code does all of this at the exact same time!  It’s really powerful!!

I went ahead and rewrote the code to align it with the VBA coding style of this blog.  If you’re curious or want to ask Ejaz a question you can view his original code and blog post, Do You Hate The Numbers Stored As Text Error. Make sure you add both the subroutine and function to your code module. Enjoy!

Sub CleanData()

'PURPOSE:Clean up selected data by trimming spaces, converting dates,
'and converting numbers to appropriate formats from text format
'AUTHOR: Ejaz Ahmed (www.StrugglingToExcel.Wordpress.com)
'SOURCE: www.TheSpreadsheetGuru.com/The-Code-Vault

Dim MessageAnswer As VbMsgBoxResult
Dim EachRange As Range
Dim TempArray As Variant
Dim rw As Long
Dim col As Long
Dim ChangeCase As Boolean
Dim ChangeCaseOption As VbStrConv
Dim rng As Range

'User Preferences
  ChangeCaseOption = vbProperCase
  ChangeCase = False

Set rng = Application.Selection

'Warn user if Range has Formulas
  If RangeHasFormulas(rng) Then
    MessageAnswer = MsgBox("Some of the cells contain formulas. " _
      & "Would you like to proceed and overwrite formulas with values?", _
      vbQuestion + vbYesNo, "Formulas Found")
    If MessageAnswer = vbNo Then Exit Sub
  End If

'Loop through each separate area the selected range may have
  For Each EachRange In rng.Areas
    TempArray = EachRange.Value2
      If IsArray(TempArray) Then
        For rw = LBound(TempArray, 1) To UBound(TempArray, 1)
          For col = LBound(TempArray, 2) To UBound(TempArray, 2)
            'Check if value is a date
              If IsDate(TempArray(rw, col)) Then
                TempArray(rw, col) = CDate(TempArray(rw, col))
              
            'Check if value is a number
              ElseIf IsNumeric(TempArray(rw, col)) Then
                TempArray(rw, col) = CDbl(TempArray(rw, col))
                  
            'Otherwise value is Text. Let's Trim it! (Remove any extraneous spaces)
              Else
                TempArray(rw, col) = Application.Trim(TempArray(rw, col))
                      
                'Change Case if the user wants to
                  If ChangeCase Then
                    TempArray(rw, col) = StrConv( _
                    TempArray(rw, col), ChangeCaseOption)
                  End If
              End If
          Next col
        Next rw
      Else
        'Handle with Single Cell selected areas
          If IsDate(TempArray) Then 'If Date
            TempArray = CDate(TempArray)
          ElseIf IsNumeric(TempArray) Then 'If Number
            TempArray = CDbl(TempArray)
          Else 'Is Text
            TempArray = Application.Trim(TempArray)
              'Handle case formatting (if necessary)
                If ChangeCase Then
                  TempArray = StrConv(TempArray, ChangeCaseOption)
                End If
          End If
      End If
      
    EachRange.Value2 = TempArray
    
  Next EachRange

'Code Ran Succesfully!
  MsgBox "Your data cleanse was successful!", vbInformation, "All Done!"

End Sub

Determine If Range Has Formulas Function

Function RangeHasFormulas(ByRef rng As Range) As Boolean

'PURPOSE: Determine if given range has any formulas in it
'AUTHOR: Ejaz Ahmed (www.StrugglingToExcel.Wordpress.com)
'SOURCE: www.TheSpreadsheetGuru.com/The-Code-Vault

Dim TempVar As Variant

TempVar = rng.HasFormula

'Test Range
  If IsNull(TempVar) Then
    'Some of cells have fromulas
      RangeHasFormulas = True
  Else
    If TempVar = True Then
      'All cells have formulas
        RangeHasFormulas = True
    Else
      'None of cells have formulas
        RangeHasFormulas = False
    End If
  End If

End Function

Using VBA Code Found On The Internet

Now that you’ve found some VBA code that could potentially solve your Excel automation problem, what do you do with it? If you don’t necessarily want to learn how to code VBA and are just looking for the fastest way to implement this code into your spreadsheet, I wrote an article (with video) that explains how to get the VBA code you’ve found running on your spreadsheet.

Getting Started Automating Excel

Are you new to VBA and not sure where to begin? Check out my quickstart guide to learning VBA. This article won’t overwhelm you with fancy coding jargon, as it provides you with a simplistic and straightforward approach to the basic things I wish I knew when trying to teach myself how to automate tasks in Excel with VBA Macros.

Also, if you haven’t checked out Excel’s latest automation feature called Power Query, I have put together a beginner’s guide for automating with Excel’s Power Query feature as well! This little-known built-in Excel feature allows you to merge and clean data automatically with little to no coding!

How Do I Modify This To Fit My Specific Needs?

Chances are this post did not give you the exact answer you were looking for. We all have different situations and it’s impossible to account for every particular need one might have. That’s why I want to share with you: My Guide to Getting the Solution to your Problems FAST! In this article, I explain the best strategies I have come up with over the years to get quick answers to complex problems in Excel, PowerPoint, VBA, you name it

I highly recommend that you check this guide out before asking me or anyone else in the comments section to solve your specific problem. I can guarantee that 9 times out of 10, one of my strategies will get you the answer(s) you are needing faster than it will take me to get back to you with a possible solution. I try my best to help everyone out, but sometimes I don’t have time to fit everyone’s questions in (there never seem to be quite enough hours in the day!).

I wish you the best of luck and I hope this tutorial gets you heading in the right direction!

Keep Learning

Chris Newman

Chris Newman

Chris is a finance professional and Excel MVP recognized by Microsoft since 2016. With his expertise, he founded TheSpreadsheetGuru blog to help fellow Excel users, where he shares his vast creative solutions & expertise. In addition, he has developed over 7 widely-used Excel Add-ins that have been embraced by individuals and companies worldwide.

[FREE Training] 10 Amazing Excel Efficiency Tricks. Why Don't People Know These?!

X