How to speed up WorksheetFunction.Trim(cCell.Value)

lovallee

Board Regular
Joined
Jul 8, 2002
Messages
216
Good day,

I run the following code for a selection of about 2 million cells and it's very slow (i.e. more than two hours!).
The worksheet is unlocked and there are no formulas linked to these cells...
How can speed up this code? Thanks!

Code:
Sub RemoveSpaces()
    Dim cCell As Range
    For Each cCell In Selection.Cells
       cCell.Value = WorksheetFunction.Trim(cCell.Value)
       
    Next cCell
End Sub
 

Some videos you may like

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type

shg

MrExcel MVP
Joined
May 7, 2008
Messages
21,782
Office Version
  1. 2010
Platform
  1. Windows
That will also replace all formulas in the selection with their values.

If you want to remove all spaces as the procedure name suggests, just find and replace space with nothing.

If the selection contains a lot of numbers (or empty cells), this will help:

Code:
Sub RemoveSpaces()
  Dim cell As Range

  On Error Resume Next
  
  With WorksheetFunction
    For Each cell In slection.Cells.SpecialCells(xlCellTypeConstants, xlTextValues)
      cell.Value = .Trim(cCell.Value)
    Next cell
  End With
End Sub
 

lovallee

Board Regular
Joined
Jul 8, 2002
Messages
216
Thank you shg,

I added the standard performance settings as below...but it's still kind of very slow...
I guess I will have to live with it!


Code:
Sub RemoveExtraSpaces()


Dim cCell As Range
On Error Resume Next
    
CalcSetting = Application.Calculation
Application.Calculation = xlCalculationManual
Application.ScreenUpdating = False


    For Each cCell In Selection.Cells.SpecialCells(xlCellTypeConstants)
        cCell.Value = WorksheetFunction.Trim(cCell.Value)
    Next cCell

Application.Calculate
Application.Calculation = CalcSetting
Application.ScreenUpdating = True

End Sub
 

shg

MrExcel MVP
Joined
May 7, 2008
Messages
21,782
Office Version
  1. 2010
Platform
  1. Windows
You're welcome.
 

lovallee

Board Regular
Joined
Jul 8, 2002
Messages
216

ADVERTISEMENT

For the benefits of MrExcel members:

I kept digging a bit and found the following, which avoid the back and forth trips between VBA and the worksheet.
Very efficient!


Credits: KjBox on OzGrid

Code:
Sub CleanTrim() 
     
    Dim x, i As Long, j As Long 
     
    x = Selection.Value 
     
    For i = 1 To UBound(x, 1) 
        For j = 1 To UBound(x, 2) 
            x(i, j) = Application.Clean(Application.Trim(x(i, j))) 
        Next 
    Next 
    Selection.value = x 
     
End Sub
 

Jonmo1

MrExcel MVP
Joined
Oct 12, 2006
Messages
44,061
You might also consider using VBA's built in TRIM function.
Instead of WorksheetFunction.Trim(cCell.Value)
just use Trim(cCell.Value)

That would be considerably faster by not calling worksheet functions.

However, Understanding the difference between the two is

WorksheetFunction.Trim removes all consecutive spaces
So if you had say "_This____Is____Cool_", it would change it to "This_is_Cool". -> note _ represents a space

But VBA's Trim would only remove the leading and trailing spaces, not the ones in the middle, so it would return "This____Is____Cool"
 

lovallee

Board Regular
Joined
Jul 8, 2002
Messages
216
Nice comment Jonmo1!

I implemented it in in my code since I am only worried about leading and trailing spaces!
Thanks!
 

Watch MrExcel Video

Forum statistics

Threads
1,123,156
Messages
5,600,049
Members
414,357
Latest member
Gemma_R

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
Top