Results 1 to 7 of 7

Search/Replace in defined array VBA

This is a discussion on Search/Replace in defined array VBA within the Excel Questions forums, part of the Question Forums category; I am just starting to learn about using arrays in VBA to improve efficiency when performing various functions across large ...

  1. #1
    Board Regular
    Join Date
    Jul 2012
    Posts
    61

    Default Search/Replace in defined array VBA

    I am just starting to learn about using arrays in VBA to improve efficiency when performing various functions across large data sets. I have an array defined as follows:

    Dim MyArray as Variant
    MyArray = Range("BS27:DS50000")


    The values in this range will either contain text or a value of zero. I want to replace all zeroes with a blank/null value. How do I write the code that does this? I have recorded the search & replace code but I believe the syntax would be different when using an array vs. actually selecting the range from the worksheet. Just FYI, here is the recorded code (minus apostrophes, of course):

    ' Range("BS27:DS50000").Replace What:="0", Replacement:="", LookAt:=xlWhole, _
    ' SearchOrder:=xlByRows, MatchCase:=False, SearchFormat:=False, _
    ' ReplaceFormat:=False
    ' Range("BS27").Select

  2. #2
    Board Regular
    Join Date
    Nov 2009
    Posts
    4,768

    Default Re: Search/Replace in defined array VBA

    maybe:
    Code:
    Dim MyArray As Variant
    MyArray = Range("BS27:DS50000")
    For i = LBound(MyArray) To UBound(MyArray)
        For j = LBound(MyArray, 2) To UBound(MyArray, 2)
            If MyArray(i, j) = 0 Then MyArray(i, j) = Empty
        Next j
    Next i
    'Range("A1:D3") = MyArray

  3. #3
    Board Regular
    Join Date
    Jul 2012
    Posts
    61

    Default Re: Search/Replace in defined array VBA

    Great, so far so good! However, I forgot to ask proper syntax for "copying" back into the original range after the search/replace has been performed. Can you help with that too please?

  4. #4
    MrExcel MVP Rick Rothstein's Avatar
    Join Date
    Apr 2011
    Location
    New Jersey, USA
    Posts
    25,966

    Default Re: Search/Replace in defined array VBA

    Quote Originally Posted by jdaywalt View Post
    The values in this range will either contain text or a value of zero. I want to replace all zeroes with a blank/null value. How do I write the code that does this? I have recorded the search & replace code but I believe the syntax would be different when using an array vs. actually selecting the range from the worksheet. Just FYI, here is the recorded code (minus apostrophes, of course):
    I would expect simply replacing the zeroes with nothing would be the fastest way to do this...
    Code:
    Sub ReplaceZeroesWithEmptyString()
      Range("BS27:DS50000").Replace 0, "", xlWhole
    End Sub
    Rick's "mini" blog... http://www.excelfox.com/forum/f22/
    .
    Want to post a small screen shot? Try MrExcel HTML Maker
    How To Use MrExcel HTML Maker: http://www.mrexcel.com/forum/about-b...ml#post2545970

  5. #5
    Board Regular
    Join Date
    Jul 2012
    Posts
    61

    Default Re: Search/Replace in defined array VBA

    Yes, Rick---that indeed worked very well! I thought the array method would be faster, but actually yours worked just as quickly. Appreciate the alternative approach!

  6. #6
    Board Regular
    Join Date
    Nov 2009
    Posts
    4,768

    Default Re: Search/Replace in defined array VBA

    Quote Originally Posted by jdaywalt View Post
    Great, so far so good! However, I forgot to ask proper syntax for "copying" back into the original range after the search/replace has been performed. Can you help with that too please?
    The answer is the penultimate line of blah below.
    The array method is faster if there are a lots of zeroes. If there are none the replace method is faster.
    Trials with all zeroes in the range was 14 times as fast on my machine. Application.ScreenUpdating = False made little difference.

    The two subs used for testing:
    Code:
    Sub blah()
    Dim MyArray As Variant
    Range("BS27:DS5000") = 0
    MyArray = Range("BS27:DS5000")
    starttime = Timer
    For i = LBound(MyArray) To UBound(MyArray)
        For j = LBound(MyArray, 2) To UBound(MyArray, 2)
            If MyArray(i, j) = 0 Then MyArray(i, j) = Empty
        Next j
    Next i
    Range("BS27:DS5000") = MyArray
    MsgBox Timer - starttime
    End Sub
    
    
    
    Sub ReplaceZeroesWithEmptyString()
    Range("BS27:DS5000") = 0
    starttime = Timer
    Range("BS27:DS5000").Replace 0, "", xlWhole
    MsgBox Timer - starttime
    End Sub
    I took a nought off your original range as my machine was starting to bend under the weight.
    Last edited by p45cal; May 15th, 2013 at 06:19 PM.

  7. #7
    Board Regular
    Join Date
    Jul 2012
    Posts
    61

    Default Re: Search/Replace in defined array VBA

    I will try both methods and see which works best (and I love your timer function---I'm stealing that too!) Either way, I love that I now have two methods in my arsenal for current AND future use. Thank you so very much!

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  


DMCA.com