Avoid For Each Loop

daniel22bg

New Member
Joined
Nov 21, 2008
Messages
31
Hi There,

I have a range of about 500 cells, some of which are empty and others are numbers. I would like to divide all the numbers with VBA by 100 without affecting the empty cells. Now i have the following Loop, which takes awfully lot of time. Can I avoid these loops somehow, so that I can optimize my code? Thanks a lot :)
Code:
Dim Rng As Range               
 
For Each Rng In Sheets("1").Range("A1:A500"))
          If Not (IsEmpty(Rng)) Then
                 Rng.Value = Rng.Value / 100
          End If
Next Rng
 

ChrisM

Well-known Member
Joined
Jun 11, 2002
Messages
2,129
I'm sure there's a better answer, but multiplying by .01 should be faster than dividing by 100. Division is one of the slower of the math functions in programming.

And then you can get rid of the IsEmpty test.
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
Hi

The PasteSpecial method and the SpecialCells method are what you need:

Code:
Dim r As Range

'first write 100 into an empty cell:

Cells(1,"IV").Value = 100
Cells(1,"IV").Copy

On Error Resume Next
Set r = Sheets("1").Range("A1:A500").SpecialCells(xlCellTypeConstants,xlNumbers)
On Error Goto 0
If Not r Is Nothing Then
  r.PasteSpecial xlPasteValues,xlPasteSpecialOperationDivide
Else
  'no number found - do something else
End if

'clean up:
Cells(1,"IV").Clear
 

Forum statistics

Threads
1,081,523
Messages
5,359,263
Members
400,523
Latest member
ExcelNewbie98

Some videos you may like

This Week's Hot Topics

  • VBA (Userform)
    Hi All, I just would like to know why my code isn't working. Here is my VBA code: [CODE=vba]Private Sub OKButton_Click() Dim i As Integer...
  • List box that changes fill color
    Hello, I have gone through so many pages trying to figure this out. I have a 2020 calendar that depending on the day needs to have a certain...
  • Remove duplicates and retain one. Cross-linked cases
    Hi all I ran out of google keywords to use and still couldn't find a reference how to achieve the results of a single count. It would be great if...
  • VBA Copy and Paste With Duplicates
    Hello All, I'm in need of some input. My VBA skills are sub-par at best. I've assembled this code from basic research and it works but is...
  • Macro
    is it possible for a macro to run if the active cell value is different to the value above it
  • IF DATE and TIME
    I currently use this to check if date has passed but i also need to set a time on it too. Is it possible? [CODE=vba]=IF(B:B>TODAY(),"Not...
Top