Consulting

Results 1 to 17 of 17

Thread: Help with making code run faster

  1. #1

    Help with making code run faster

    I am using the code below to sort through a massive amount of data (>50,000 lines.) The code below works but it takes about 15-20 minutes to run and I was wondering if there were any secrets that make it run faster.
    Cells.AutoFilter
    
    Range("f" & Rows.Count).End(xlUp).EntireRow.Interior.Color = 49407
    
    Cells.Find(What:="LIFO Pool", After:=ActiveCell, LookIn:=xlFormulas _
    , LookAt:=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlNext, MatchCase:=False, SearchFormat:=True).Select
    ActiveCell.Offset(1).Select
    
    pool = ActiveCell.Value
    vend = ActiveCell.Offset(, 1).Value
    
    Do Until ActiveCell.Value = "" And ActiveCell.Interior.Color = 49407
    'skips over cells that are grey and pink
    If ActiveCell.Offset(, 1).Interior.Color <> 12632256 And ActiveCell.Interior.Color <> 8421631 Then
    If ActiveCell.Value = "" Then
    ActiveCell.Value = pool
    ElseIf ActiveCell.Value <> "" Then
    pool = ActiveCell.Value
    End If
    
    If ActiveCell.Offset(, 1).Value = "" Then
    ActiveCell.Offset(, 1).Value = vend
    ElseIf ActiveCell.Offset(, 1).Value <> "" Then
    vend = ActiveCell.Offset(, 1).Value
    End If
    End If
    
    If ActiveCell.Value = "" Then
    ActiveCell.Value = pool
    ElseIf ActiveCell.Value <> "" Then
    pool = ActiveCell.Value
    End If
    
    Hierarchy = ActiveCell.Offset(, 2).Value
    ActiveCell.Offset(, 2).Value = Hierarchy
    ActiveCell.Offset(, -1).Value = ActiveCell.Value & ActiveCell.Offset(, 1).Value & ActiveCell.Offset(, 2).Value
    ActiveCell.Offset(1).Select
    Loop
    Last edited by SamT; 07-25-2017 at 01:04 PM.

  2. #2
    VBAX Sage SamT's Avatar
    Joined
    Oct 2006
    Location
    Near Columbia
    Posts
    7,814
    Location
    First, stop using Interior.Color = Some RGB value.
    Excel changes that RGB value to the closest match in the Cells Format ColorPicker dialog. (For example, on my machine, 49407 translates to an Orange, ColorIndex 44.) Then, when you ask it to check the Cell's interior.Color, it has to perform an RGB fucntion,Change the value to the nearest match, then compare.

    If you use Interior.ColorIndex, then Excel just looks in a table. BTW, the ColorIndex of nearest shade of Grey to that RGB on my machine is 15. 8421631, a pink, ColorIndex is 22

    Change the Address in this snippet to one of your 49407 colored cells and run
    Sub t()
    
    With Range("A1")
    .Value = .Interior.ColorIndex
    End With
    End Sub
    to find the actual ColorIndex Excel is using for that RGB value

    You can make a table of all ColorIndices and matching hues with
    Sub ColorIndices()
    Dim i as long
    With Range("A:A")
    With .Cells(i)
    .Value = i
    .Interior.ColorIndex = i
    End With
    End With
    Next
    Second. Quit using "ActiveCell." Everytime VBA sees "ActiveCell" it has to look at he Worksheet to see which cell is currently active.

    Dim Found as Range 'Don't skip using Found and Checking it for Nothing. That way lies madness!
    Dim PoolCell As Range
    Dim VendCell As Range
    
    Set Found = [LIFOPoolColumn].Find(What:="LIFO Pool", LookIn:=xlFormulas _ 
    , LookAt:=xlPart,  MatchCase:=False, SearchFormat:=True) 
    'Are you sure about SearchFormat? I cannot see where you set up the prerequisites for using it.
    'Edit [LIFOPoolColumn] to the Column Address, Ex(Range("Z:Z"))
    'Hard to give perfect advice, since I can't see the worksheet
    If Found is Nothing, then Exit Sub
    
    set PoolCell = Found.Offset(1)
    Set VendCell = PoolCell.Offset(, 1)
    
    'Start loop
    'Blah Edit all ActiveCell to PoolCell
    'Blah Edit all ActiveCell.Offset(, 1) to VendCell
    'blah
    'blah
    
    'At the botttom of the loop,
    'Instead of ActiveCell.Offset(1).Select 
    Set PoolCell = PoolCell.Offset(1)
    Set VendCell = VendCell.Offset(1)
    loop
    I expect the student to do their homework and find all the errrors I leeve in.


    Please take the time to read the Forum FAQ

  3. #3
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    If you post a representative sample of your data that would help
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  4. #4
    Example Reports.xlsm
    Quote Originally Posted by mdmackillop View Post
    If you post a representative sample of your data that would help
    Here is a sample of my data. The macro is already in this spreadsheet and is labeled "Testthis." I had to modify my code a little due to the number of columns I actually created in the "sample" document.

  5. #5
    Quote Originally Posted by SamT View Post
    First, stop using Interior.Color = Some RGB value.
    Excel changes that RGB value to the closest match in the Cells Format ColorPicker dialog. (For example, on my machine, 49407 translates to an Orange, ColorIndex 44.) Then, when you ask it to check the Cell's interior.Color, it has to perform an RGB fucntion,Change the value to the nearest match, then compare.

    If you use Interior.ColorIndex, then Excel just looks in a table. BTW, the ColorIndex of nearest shade of Grey to that RGB on my machine is 15. 8421631, a pink, ColorIndex is 22

    Change the Address in this snippet to one of your 49407 colored cells and run
    Sub t()
    
    With Range("A1")
    .Value = .Interior.ColorIndex
    End With
    End Sub
    to find the actual ColorIndex Excel is using for that RGB value

    You can make a table of all ColorIndices and matching hues with
    Sub ColorIndices()
    Dim i as long
    With Range("A:A")
    With .Cells(i)
    .Value = i
    .Interior.ColorIndex = i
    End With
    End With
    Next
    Second. Quit using "ActiveCell." Everytime VBA sees "ActiveCell" it has to look at he Worksheet to see which cell is currently active.

    Dim Found as Range 'Don't skip using Found and Checking it for Nothing. That way lies madness!
    Dim PoolCell As Range
    Dim VendCell As Range
    
    Set Found = [LIFOPoolColumn].Find(What:="LIFO Pool", LookIn:=xlFormulas _ 
    , LookAt:=xlPart,  MatchCase:=False, SearchFormat:=True) 
    'Are you sure about SearchFormat? I cannot see where you set up the prerequisites for using it.
    'Edit [LIFOPoolColumn] to the Column Address, Ex(Range("Z:Z"))
    'Hard to give perfect advice, since I can't see the worksheet
    If Found is Nothing, then Exit Sub
    
    set PoolCell = Found.Offset(1)
    Set VendCell = PoolCell.Offset(, 1)
    
    'Start loop
    'Blah Edit all ActiveCell to PoolCell
    'Blah Edit all ActiveCell.Offset(, 1) to VendCell
    'blah
    'blah
    
    'At the botttom of the loop,
    'Instead of ActiveCell.Offset(1).Select 
    Set PoolCell = PoolCell.Offset(1)
    Set VendCell = VendCell.Offset(1)
    loop
    IF the LIFOpoolcolumn is column B how to I set that up in your found variable?

  6. #6
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,738
    Location
    I'm not following all the .Color testing logic (not even sure it's needed)

    Try this --

    WS Report 1 is your data
    WS Original is a copy to re-init Report 1 after testing the macro
    WS After is the results of your macro that I was using as a check


    Option Explicit
    Sub testthis_1()
        Dim rowLast As Range, rowFirst As Range, cellBlanks As Range
     
       Application.ScreenUpdating = False
        
        With Worksheets("Report 1")
            Set rowFirst = .Cells.Find(What:="LIFO Pool", After:=.Cells(1, 1), _
                LookIn:=xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, _
                SearchDirection:=xlNext, MatchCase:=False, SearchFormat:=True)
            Set rowLast = .Cells(.Rows.Count, 2).End(xlUp).Offset(0, 1)
    '        MsgBox rowFirst.Address & " -- " & rowLast.Address
            
            Set cellBlanks = Nothing
            On Error Resume Next
            Set cellBlanks = Range(rowFirst, rowLast).SpecialCells(xlCellTypeBlanks)
            If Not cellBlanks Is Nothing Then
                cellBlanks.Formula = "=R[-1]C"
                cellBlanks.Copy
                cellBlanks.PasteSpecial (xlPasteValues)
            End If
            
            Set rowFirst = rowFirst.Offset(1, -1)
            Set rowLast = rowLast.Offset(0, -2)
    '        MsgBox rowFirst.Address & " -- " & rowLast.Address
            Range(rowFirst, rowLast).Formula = "=RC[1] & RC[2] & RC[3]"
            Range(rowFirst, rowLast).Copy
            Range(rowFirst, rowLast).PasteSpecial (xlPasteValues)
        End With
     
       Application.ScreenUpdating = True
    End Sub
    Attached Files Attached Files
    Last edited by Paul_Hossler; 07-26-2017 at 07:26 AM. Reason: Typo
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  7. #7
    Paul and Sam you both are geniuses, however I did forget one thing the bit of code below is used to eliminate all zeros in front of the first number in column D. For example I have a cell that says "0201002" this is stored as text in the original file I need this to actually shw "201002"

    Hierarchy = ActiveCell.Offset(, 2).Value 
        ActiveCell.Offset(, 2).Value = Hierarchy
    Sam I tried your code with the added details below and it still returned the "0201002" number

    Set Hierarchy = poolcell.offset(,2).value
    Poolcell.offset(,2).value = Hierarchy

  8. #8
    Quote Originally Posted by Paul_Hossler View Post
    I'm not following all the .Color testing logic (not even sure it's needed)

    Try this --

    WS Report 1 is your data
    WS Original is a copy to re-init Report 1 after testing the macro
    WS After is the results of your macro that I was using as a check


    Option Explicit
    Sub testthis_1()
        Dim rowLast As Range, rowFirst As Range, cellBlanks As Range
     
       Application.ScreenUpdating = False
        
        With Worksheets("Report 1")
            Set rowFirst = .Cells.Find(What:="LIFO Pool", After:=.Cells(1, 1), _
                LookIn:=xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, _
                SearchDirection:=xlNext, MatchCase:=False, SearchFormat:=True)
            Set rowLast = .Cells(.Rows.Count, 2).End(xlUp).Offset(0, 1)
    '        MsgBox rowFirst.Address & " -- " & rowLast.Address
            
            Set cellBlanks = Nothing
            On Error Resume Next
            Set cellBlanks = Range(rowFirst, rowLast).SpecialCells(xlCellTypeBlanks)
            If Not cellBlanks Is Nothing Then
                cellBlanks.Formula = "=R[-1]C"
                cellBlanks.Copy
                cellBlanks.PasteSpecial (xlPasteValues)
            End If
            
            Set rowFirst = rowFirst.Offset(1, -1)
            Set rowLast = rowLast.Offset(0, -2)
    '        MsgBox rowFirst.Address & " -- " & rowLast.Address
            Range(rowFirst, rowLast).Formula = "=RC[1] & RC[2] & RC[3]"
            Range(rowFirst, rowLast).Copy
            Range(rowFirst, rowLast).PasteSpecial (xlPasteValues)
        End With
     
       Application.ScreenUpdating = True
    End Sub
    Paul the color logic was meant to tell excel when to stop and what lines to copy down. Your code accomplishes the same thing just a lot faster without the color index.

  9. #9
    VBAX Master Aflatoon's Avatar
    Joined
    Sep 2009
    Location
    UK
    Posts
    1,728
    Location
    Quote Originally Posted by SamT View Post
    First, stop using Interior.Color = Some RGB value.
    Excel changes that RGB value to the closest match in the Cells Format ColorPicker dialog. (For example, on my machine, 49407 translates to an Orange, ColorIndex 44.) Then, when you ask it to check the Cell's interior.Color, it has to perform an RGB fucntion,Change the value to the nearest match, then compare.

    If you use Interior.ColorIndex, then Excel just looks in a table. BTW, the ColorIndex of nearest shade of Grey to that RGB on my machine is 15. 8421631, a pink, ColorIndex is 22
    Of course, that is only true for Excel 2003 and older.
    Be as you wish to seem

  10. #10
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,738
    Location
    Quote Originally Posted by greyangel View Post
    Paul and Sam you both are geniuses, however I did forget one thing the bit of code below is used to eliminate all zeros in front of the first number in column D. For example I have a cell that says "0201002" this is stored as text in the original file I need this to actually shw "201002"
    Change the one line andsee if it works

            Range(rowFirst, rowLast).Formula = "=RC[1] & RC[2] & IF(ISERROR(NUMBERVALUE(RC[3])),RC[3],NUMBERVALUE(RC[3]))"
    Attached Files Attached Files
    Last edited by Paul_Hossler; 07-26-2017 at 05:09 PM.
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  11. #11
    VBAX Sage SamT's Avatar
    Joined
    Oct 2006
    Location
    Near Columbia
    Posts
    7,814
    Location
    Quote Originally Posted by greyangel View Post
    IF the LIFOpoolcolumn is column B how to I set that up in your found variable?
    Set Found = Range("B"B").Find(What:="LIFO Pool", LookIn:=xlFormulas _ 
    , LookAt:=xlPart,  MatchCase:=False, SearchFormat:=True)
    I expect the student to do their homework and find all the errrors I leeve in.


    Please take the time to read the Forum FAQ

  12. #12
    [QUOTE=Paul_Hossler;365928]
    Quote Originally Posted by greyangel View Post
    Paul and Sam you both are geniuses, however I did forget one thing the bit of code below is used to eliminate all zeros in front of the first number in column D. For example I have a cell that says "0201002" this is stored as text in the original file I need this to actually shw "201002"

    Change the one line andsee if it works

            Range(rowFirst, rowLast).Formula = "=RC[1] & RC[2] & IF(ISERROR(NUMBERVALUE(RC[3])),RC[3],NUMBERVALUE(RC[3]))"
    I used your code and added a few lines of code to the very beginning.

    Option Explicit
    Sub testthis_1()
    Application.screenupdating = false
    Columns("D:D").TextToColumns Destination:=Columns("D:D"), DataType:=xlDelimited, _
        TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=True, _
        Semicolon:=False, Comma:=False, Space:=False, Other:=False, FieldInfo _
        :=Array(1, 1), TrailingMinusNumbers:=True
        Dim rowLast As Range, rowFirst As Range, cellBlanks As Range
        
        With Worksheets("P555021 - Matched Summary")
            Set rowFirst = .Cells.Find(What:="LIFO Pool", After:=.Cells(1, 1), _
                LookIn:=xlFormulas, LookAt:=xlPart, SearchOrder:=xlByRows, _
                SearchDirection:=xlNext, MatchCase:=False, SearchFormat:=True)
            Set rowLast = .Cells(.Rows.Count, 2).End(xlUp).Offset(0, 1)
    '        MsgBox rowFirst.Address & " -- " & rowLast.Address
            
            Set cellBlanks = Nothing
            On Error Resume Next
            Set cellBlanks = Range(rowFirst, rowLast).SpecialCells(xlCellTypeBlanks)
            If Not cellBlanks Is Nothing Then
                cellBlanks.Formula = "=R[-1]C"
                cellBlanks.Copy
                cellBlanks.PasteSpecial (xlPasteValues)
            End If
            
            Set rowFirst = rowFirst.Offset(1, -1)
            Set rowLast = rowLast.Offset(0, -2)
    '        MsgBox rowFirst.Address & " -- " & rowLast.Address
            Range(rowFirst, rowLast).Formula = "=RC[1] & RC[2] & IF(ISERROR(NUMBERVALUE(RC[3])),RC[3],NUMBERVALUE(RC[3]))"
            Range(rowFirst, rowLast).Copy
            Range(rowFirst, rowLast).PasteSpecial (xlPasteValues)
        
        
        
        End With
        
        
        Application.ScreenUpdating = True
    End Sub

  13. #13
    VBAX Sage SamT's Avatar
    Joined
    Oct 2006
    Location
    Near Columbia
    Posts
    7,814
    Location
    @ Aflatoon,
    In later version is checking cells for RGB values as fast as checking for ColorIndices? I just :
    I expect the student to do their homework and find all the errrors I leeve in.


    Please take the time to read the Forum FAQ

  14. #14
    VBAX Sage SamT's Avatar
    Joined
    Oct 2006
    Location
    Near Columbia
    Posts
    7,814
    Location
    Quote Originally Posted by greyangel View Post
    I have a cell that says "0201002" this is stored as text in the original file I need this to actually shw "201002"
    Assuming no Alpha characters in Value and that the value is always numerically less than 2147483647;
    Hierarchy = CStr(Clng(poolcell.offset(,2).value))
    That assumes no (decimal) dots or commas in value. Else use
    Hierarchy = CStr(CDbl(poolcell.offset(,2).value))
    I expect the student to do their homework and find all the errrors I leeve in.


    Please take the time to read the Forum FAQ

  15. #15
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,738
    Location
    Quote Originally Posted by greyangel View Post
    I used your code and added a few lines of code to the very beginning.

    And did it still work?
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  16. #16
    Quote Originally Posted by Paul_Hossler View Post
    And did it still work?
    Yeah it worked like a charm. Also this code took less than a minute to run, I say job well done.

  17. #17
    VBAX Master Aflatoon's Avatar
    Joined
    Sep 2009
    Location
    UK
    Posts
    1,728
    Location
    Quote Originally Posted by SamT View Post
    @ Aflatoon,
    In later version is checking cells for RGB values as fast as checking for ColorIndices? I just :
    As far as I know. They aren't the same thing though, so the question is moot, in my opinion.
    Be as you wish to seem

Posting Permissions

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