rjtaylor

New Member
Joined
Jan 27, 2004
Messages
36
I have some code that looks through 10032 entries with 10020 entries so a double loop It was taking about 1 minute and 45 seconds Now for some reason it takes just under 4 minutes Is there a better/Faster way
Code:
Sub FindDifference()
 Dim varSheetA As Variant
    Dim varSheetB As Variant
    Dim strRangeToCheck As String
    Dim AircraftFound As Boolean
    Dim Sht As Worksheet
    Dim RowCount As Integer, RowCount2 As Integer
    
'    find out how many rows are needed
'    First check worksheet (Aircraft Data)
    Set Sht = Worksheets("OrigCheck")
    RowCount = Sht.Cells(Sht.Rows.Count, "B").End(xlUp).Row
    
'    Now Check worksheet (NewData)
    Set Sht = Worksheets("NewData")
    RowCount2 = Sht.Cells(Sht.Rows.Count, "A").End(xlUp).Row
    If RowCount2 > RowCount Then RowCount = RowCount2
    
'   Add one so the number we are checking is the same or higher
'   since one sheet starts on cell A1 and the other starts on Cell A2
    RowCount = RowCount + 1
    
    strRangeToCheck = "G" & RowCount

    
'    set arrays instead of looping through a range to speed up the process
    varSheetA = Worksheets("NewData").Range("A1:" & strRangeToCheck)
    varSheetB = Worksheets("OrigCheck").Range("A2:" & strRangeToCheck)
    Debug.Print Now
    
    For j = LBound(varSheetA, 1) To UBound(varSheetA, 1)
        If varSheetA(j, 1) <> "" Then
            For jj = LBound(varSheetB, 1) To UBound(varSheetB, 1)
                If UCase(varSheetA(j, 1)) = UCase(varSheetB(jj, 1)) And _
                    UCase(varSheetA(j, 2)) = UCase(varSheetB(jj, 2)) And _
                    UCase(varSheetA(j, 3)) = UCase(varSheetB(jj, 3)) And _
                    UCase(varSheetA(j, 4)) = UCase(varSheetB(jj, 4)) And _
                    UCase(varSheetA(j, 5)) = UCase(varSheetB(jj, 5)) And _
                    UCase(varSheetA(j, 6)) = UCase(varSheetB(jj, 6)) And _
                    UCase(varSheetA(j, 7)) = UCase(varSheetB(jj, 7)) Then
                        AircraftFound = True
                        GoTo Skip1
                End If
            Next
Skip1:
'Now if a differance is found add it to the "Diff File" worksheet
            If AircraftFound = True Then
                AircraftFound = False
            Else
                For Each cell In Range("DiffManufacturer")
                    If cell.Value = "" Then
                        cell.Value = varSheetA(j, 1)
                        cell.Offset(0, 1) = varSheetA(j, 2)
                        cell.Offset(0, 2) = varSheetA(j, 3)
                        cell.Offset(0, 3) = varSheetA(j, 4)
                        cell.Offset(0, 4) = varSheetA(j, 5)
                        cell.Offset(0, 5) = varSheetA(j, 6)
                        cell.Offset(0, 6) = varSheetA(j, 7)
'                        cell.Offset(0, 7) = varSheetA(j, 8)
                        Exit For
                    End If
                Next
            End If
        End If
    Next
    Debug.Print Now
End Sub
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Re: Is there a faster way

Hi ,

Can you try by introducing two helper columns , one in each worksheet , where you concatenate the data from the 7 cells ?

Then rather than looking for a match by looping over thousands of rows , you could use the MATCH function from one helper column to the other.
 
Upvote 0
Why are you looping thru the diff table looking for the next blank cell keep a counter and only increment it when you have a new entry to add
Code:
If aircraftfound then
     Aircraftfound = false
Else
     K=k+1
     Worksheets("diff").range("A" & k).value = varsheetA(j,1)
     Repeat for other bits
End if

That way you are not looping thru diff for every entry you want to add
 
Upvote 0
Re: Is there a faster way

Thanks I like that idea but not quite sure how to do it. I will need to research unless you have an example
 
Upvote 0
Thanks NARAYANK991 I applied your idea and got it down to 6 seconds. From 3 min 45 seconds down to 6 seconds is amazing. After setting up a sub to CONCATENATE the data in both worksheets I then ran the following code
Code:
 Public Sub FindDifference()
    Dim varSheetA As Variant
    Dim RowCount As Integer, RowCount2 As Integer
    Dim rng As Range, rng2 As String
    Dim aNumber As Variant
    Dim rowNum As Long, k As Integer
Debug.Print Now
varSheetA = Worksheets("NewData").Range("H1:H10020")
    For j = LBound(varSheetA, 1) To UBound(varSheetA, 1)
        If varSheetA(j, 1) <> "" Then
            aNumber = varSheetA(j, 1)
            Set rng = Worksheets("OrigCheck").Range("H1:H10035")
    
            If Not IsError(Application.Match(aNumber, rng, 0)) Then
                rowNum = Application.Match(aNumber, rng, 0)
            Else
                k = k + 1
                Worksheets("NewData").Activate
                rng2 = "A" & j & ":G" & j
                Range(rng2).Copy
                Worksheets("Diff File").Activate
                Worksheets("Diff File").Range("A" & k).Select
                ActiveSheet.Paste
            End If
        End If
    Next
Debug.Print Now
Debug.Print n
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,990
Messages
6,122,625
Members
449,093
Latest member
catterz66

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