Convert multiple columns from numbers to text dynamic range VBA

silentwolf

Well-known Member
Joined
May 14, 2008
Messages
1,216
Office Version
  1. 2016
Hi guys

a little stuck to find the best solution to non continious columns to change from number format to text format using VBA.

This is what I got for a single Column...

Say I like to change in active sheet Column A, D, F to text

VBA Code:
Sub ConvertNumberToText()
    With Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row)
    .NumberFormat = "@"
     .Value = .Value
    End With
End Sub

In the above code do I need .value = .Value?

Thanks for help
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
Does this work?

VBA Code:
Sub ConvertNumberToText()
    With Intersect(Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row).EntireRow, Range("A:A, D:D, F:F"))
        Debug.Print .Address
        .NumberFormat = "@"
        .Value = .Value
    End With
End Sub
 
Upvote 0
try the following:

VBA Code:
Sub ConvertNumberToText()
Dim r1 As Range
Dim r2 As Range
Dim r3 As Range
Dim rng As Range

Set r1 = Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row)
Set r2 = Range("d2:d" & Cells(Rows.Count, 1).End(xlUp).Row)
Set r3 = Range("f2:f" & Cells(Rows.Count, 1).End(xlUp).Row)
Set rng = Union(r1, r2, r3)

    With rng
        .NumberFormat = "@"
    End With
End Sub
 
Upvote 0
One way is to use an Array to store your column letters.
The nice thing about this option is if you ever have to add or remove columns to the list, you only need add/remove them to your array.
You won't need to modify any other part of the code.
VBA Code:
Sub ConvertNumberToText()

    Dim cols
    Dim i As Long
    Dim c As String
    Dim lr As Long
    
    cols = Array("A", "D", "F")

    For i = LBound(cols) To UBound(cols)
'       Get column letter
        c = cols(i)
'       Find last row
        lr = Cells(Rows.Count, c).End(xlUp).Row
        With Range(Cells(2, c), Cells(lr, c))
            .NumberFormat = "@"
            .Value = .Value
        End With
    Next i
    
End Sub
 
Upvote 0
Another option
VBA Code:
Sub ConvertNumberToText()
   Dim i As Long
   Dim Ary As Variant
   Ary = Array(0, 3, 5)
   For i = 0 To UBound(Ary)
      With Range("A2:A" & Cells(Rows.Count, 1).End(xlUp).Row)
         .Offset(, Ary(i)).TextToColumns , xlDelimited, , , 0, 0, 0, 0, 0, , Array(1, 2)
      End With
   Next i
End Sub
You're code does not change the numbers to text, it just changes the format of the cell.
 
Upvote 0
Hi guys,

did not see you..) well there is planty to choose from and I will test it sure there are all working out :)

Many thanks to all of you!!!
 
Upvote 0
I have written my own and maybe someone consider it better and useful
VBA Code:
Sub ConvertSelectedRangeToText()
       Dim rng As Range
       Set rng = selection
       
       Call ConvertRangeToText(rng)
End Sub

Sub ConvertRangeToText(rng As Range)
   On Error GoTo ErrorHandler
      
      With Application
         .ScreenUpdating = False
         .EnableEvents = False
         .Calculation = xlCalculationManual
      End With
       
       Set rng = GetUsableRange(rng)
       Dim c As Range
       For Each c In rng.Columns
            c.TextToColumns destination:=c, DataType:=xlDelimited, _
               TextQualifier:=xlTextQualifierNone, ConsecutiveDelimiter:=False, Tab:=False, _
               Semicolon:=False, Comma:=False, Space:=False, Other:=False, FieldInfo:=Array(1, 2)
       Next c
       
      With Application
         .ScreenUpdating = True
         .EnableEvents = True
         .Calculation = xlCalculationAutomatic
      End With
 Exit Sub
ErrorHandler:
       MsgBox "An error occurred while converting the range to text.", vbExclamation + vbOKOnly, "Error"
      Err.Clear
       
      With Application
         .ScreenUpdating = True
         .EnableEvents = True
         .Calculation = xlCalculationAutomatic
      End With
End Sub

Function GetUsableRange(rng As Range) As Range
    If rng Is Nothing Then
        Set GetUsableRange = Nothing
        Exit Function
    End If
    
    Dim intersection As Range
    Set intersection = Application.Intersect(rng, rng.Worksheet.UsedRange)
    
    If intersection Is Nothing Then
        Set GetUsableRange = Nothing
    Else
        Set GetUsableRange = intersection
    End If
End Function
 
Upvote 0

Forum statistics

Threads
1,224,847
Messages
6,181,325
Members
453,032
Latest member
Pauh

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