I know this doesn't necessarily address your specific problem, but I have a 
recommendation for you.
If your files are 4Mb+, then that implies thtat you have a lot of rows.
in which case, vLookups can be time consuming.
I have sample data of 100,000 rows.
and the lookup sheet has 80,000 rows.

using Vlookup to retrieve relevent data takes approximately 7-8 minutes on my 
workstation (using Excel 2010).

But, if I utilize a Dictionary Object to store the relevent data, then look in 
the Dictionary for the lookup data, it takes 12 seconds.

Here is are the macros I threw together.  
It also has the benefit of never CREATING #N/A values that later have to be 
removed.
(of course, this macro goes into a "standard" module rather than a "sheet" 
module since it moves between sheets.)

hope this helps.

Option Explicit
Public Dict_Records
Sub Flag_Processed()
    Dim R, nRows, rcnt, msg
    Dim tStart, tStop, TElapsed, TMin, TSec
    tStart = Timer
    Application.ScreenUpdating = False
    '---------------------------
    rcnt = Load_Dict
    If Dict_Records.Count > 0 Then
        nRows = Application.WorksheetFunction.CountA(Sheets("Validation Not 
Done").Range("A1:A200000"))
        For R = 2 To nRows
            If (Dict_Records.exists(Sheets("Validation Not Done").Cells(R, 
"A").Value)) Then
                Sheets("Validation Not Done").Cells(R, "B").Value = 
Dict_Records.Item(Sheets("Validation Not Done").Cells(R, "A").Value)
            End If
        Next R
    End If
    Application.ScreenUpdating = True
    '---------------------------
    tStop = Timer
    TElapsed = tStop - tStart
    TMin = 0
    TMin = TElapsed \ 60
    TSec = TElapsed Mod 60
    msg = "Flag_Processed:" & Chr(13) & Chr(13)
    If (TMin > 0) Then msg = msg & TMin & " mins "
    msg = msg & TSec & " sec"
    MsgBox msg
    '---------------------------
    
End Sub
Function Load_Dict()
    Dim R, nRows
    Set Dict_Records = CreateObject("Scripting.Dictionary")
    Dict_Records.RemoveAll
    nRows = 
Application.WorksheetFunction.CountA(Sheets("Processed").Range("A1:A200000"))
    For R = 2 To nRows
        If (Not Dict_Records.exists(Sheets("Processed").Cells(R, "A").Value)) 
Then
                Dict_Records.Add Sheets("Processed").Cells(R, "A").Value, 
Sheets("Processed").Cells(R, "B").Value
        End If
    Next R
    Load_Dict = Dict_Records.Count
End Function

 
Paul
-----------------------------------------
“Do all the good you can,
By all the means you can,
In all the ways you can,
In all the places you can,
At all the times you can,
To all the people you can,
As long as ever you can.” - John Wesley
-----------------------------------------




________________________________
From: nitin arora <nitinaror...@gmail.com>
To: excel-macros@googlegroups.com
Sent: Wed, January 4, 2012 8:19:54 AM
Subject: Re: $$Excel-Macros$$ Fwd: V lookup using macros


Hi Noorain,

I am extremely sorry for the mistake. However all the files that I have are of 
more than 4 mb in size and gmail is not allowing me to send more than 4 mb of 
data. I am pasting the codes for macro 3 used in the sheet . Please let me know 
if there is any other way by which i can upload the file in the group. Many 
Thanks.

This macro compares Transaction ID's in Sheet 1  with transaction ID's in 
Processed sheet and inserts researcher NAmes wherever the Transaction ID's 
match. Nest it deletes all the "N/A" in Researcher name column and then selects 
a filter for the date (mostly yesterday's date- added manually in Macro 3). if 
it finds that date which is manually added then it works fine but if it does 
not 
finds a date then it stops. I want a solution for this problem only that it 
should still continue even if it does not find a date and should move to next 
macro.

Codes:

Sub Macro3()
'
' Macro3 Macro
'

   ActiveSheet.ShowAllData
    ActiveSheet.Range("$A$1:$X$15000").AutoFilter Field:=2, Criteria1:="<>"
    Columns("B:B").Select
    Selection.ClearContents
    Range("C5").Select
    ActiveSheet.ShowAllData
   ' Range("B2").Select
    'ActiveCell.FormulaR1C1 = "=VLOOKUP(RC[-1],Processed!C[-1]:C,2,FALSE)"
   'Selection.AutoFill Destination:=Range("B2:B15000")
    Range("B2:B15000").Select
    Range("B2").Value = "=VLOOKUP(A2,Processed!A:C,3,FALSE)"
    Selection.FillDown
    ActiveSheet.Range("$A$1:$V$15000").AutoFilter Field:=2, Criteria1:="#N/A"
    Range("B2").Select
    Range(Selection, Selection.End(xlDown)).Select
    Selection.ClearContents
    ActiveSheet.ShowAllData
    
    'If Range("B2").Value Is Not Null Then
   
    ActiveSheet.Range("$A$1:$X$15000").AutoFilter Field:=2, Criteria1:="<>", 
Operator:=xlFilterValues
    'ActiveWindow.ScrollColumn = 2
    'ActiveWindow.ScrollColumn = 3
    'ActiveWindow.ScrollColumn = 4
   ' ActiveWindow.ScrollColumn = 5
   ' ActiveWindow.ScrollColumn = 6
    'ActiveWindow.ScrollColumn = 7
    ActiveSheet.Range("$A$1:$X$15000").AutoFilter Field:=18, Operator:= _
        xlFilterValues, Criteria2:=Array(2, "12/30/2011")
    ActiveWindow.ScrollColumn = 6
    ActiveWindow.ScrollColumn = 5
    ActiveWindow.ScrollColumn = 4
    ActiveWindow.ScrollColumn = 3
    ActiveWindow.ScrollColumn = 2
    ActiveWindow.ScrollColumn = 1
    Range("B2:B15000").Select
    Selection.ClearContents
    'Range("C269").Select
    ActiveSheet.ShowAllData
    ActiveSheet.Range("$A$1:$X$15000").AutoFilter Field:=2, Criteria1:="<>", 
Operator:=xlFilterValues
    ActiveWindow.ScrollColumn = 2
    ActiveWindow.ScrollColumn = 3
    ActiveWindow.ScrollColumn = 4
    ActiveWindow.ScrollColumn = 5
    ActiveWindow.ScrollColumn = 6
    ActiveWindow.ScrollColumn = 7
    ActiveWindow.ScrollColumn = 8
    ActiveWindow.ScrollColumn = 9
    ActiveWindow.ScrollColumn = 8
    ActiveWindow.ScrollColumn = 7
    ActiveWindow.ScrollColumn = 6
    ActiveWindow.ScrollColumn = 5
    ActiveWindow.ScrollColumn = 4
    ActiveWindow.ScrollColumn = 3
    ActiveWindow.ScrollColumn = 2
    ActiveWindow.ScrollColumn = 1
    Cells.Select
    Selection.Copy
    Sheets("Validation Not Done").Select
    'Sheets("Sheet1").Name = "Validation Not Done"
    Cells.Select
    ActiveSheet.Paste
End Sub




 
On Wed, Jan 4, 2012 at 4:48 PM, NOORAIN ANSARI <noorain.ans...@gmail.com> wrote:

Dear Nitin,
>
>Attached File is in protected mod, we are unable to view Macro 3 
>
>
>
>
>On Wed, Jan 4, 2012 at 11:00 AM, nitin arora <nitinaror...@gmail.com> wrote:
>
>
>>
>>Hi,
>>
>>I am facing a problem with Macro 3 in the sheets attached. At times the macro 
>>woks fine and at times it does not. The reason for the same is that when it 
>>does 
>>not find the date mentioned in Macro 3 it does not works fine. I was 
>>wondering 
>>if there is any way that the macro asks for a date to compare and if it does 
>>not 
>>finds that date then it should skip the step and proceed to next macro in 
>>call 
>>all macro.
>>
>>If you look at the sheet attached macro was unable to find date "1/3/2012" 
>>against researcher name.
>>
>>relevant extract:
>>
>>
>>Jan 4 file:
>>
>>ActiveSheet.Range("$A$1:$X$15000").AutoFilter Field:=18, Operator:= _
>>        xlFilterValues, Criteria2:=Array(2, "1/3/2012")
>>
>>Please let me know if you want any further details. It would be great help if 
>>I 
>>can get the solution for the same.
>>
>>Regards,
>>
>>Nitin Arora
>>
>>-- 
>>FORUM RULES (986+ members already BANNED for violation)
>> 
>>1) Use concise, accurate thread titles. Poor thread titles, like Please Help, 
>>Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not 
>>get 
>>quick attention or may not be answered.
>> 
>>2) Don't post a question in the thread of another member.
>> 
>>3) Don't post questions regarding breaking or bypassing any security measure.
>> 
>>4) Acknowledge the responses you receive, good or bad.
>> 
>>5) Cross-promotion of, or links to, forums competitive to this forum in 
>>signatures are prohibited. 
>>
>> 
>>NOTE : Don't ever post personal or confidential data in a workbook. Forum 
>>owners 
>>and members are not responsible for any loss.
>> 
>>------------------------------------------------------------------------------------------------------
>>
>>To post to this group, send email to excel-macros@googlegroups.com
>>
>
>
>-- 
>
>Thanks & regards,
>Noorain Ansari
>http://excelmacroworld.blogspot.com/
>http://noorain-ansari.blogspot.com/
>
>-- 
>FORUM RULES (986+ members already BANNED for violation)
> 
>1) Use concise, accurate thread titles. Poor thread titles, like Please Help, 
>Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get 
>quick attention or may not be answered.
> 
>2) Don't post a question in the thread of another member.
> 
>3) Don't post questions regarding breaking or bypassing any security measure.
> 
>4) Acknowledge the responses you receive, good or bad.
> 
>5) Cross-promotion of, or links to, forums competitive to this forum in 
>signatures are prohibited. 
>
> 
>NOTE : Don't ever post personal or confidential data in a workbook. Forum 
>owners 
>and members are not responsible for any loss.
> 
>------------------------------------------------------------------------------------------------------
>
>To post to this group, send email to excel-macros@googlegroups.com
>
-- 
FORUM RULES (986+ members already BANNED for violation)
 
1) Use concise, accurate thread titles. Poor thread titles, like Please Help, 
Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get 
quick attention or may not be answered.
 
2) Don't post a question in the thread of another member.
 
3) Don't post questions regarding breaking or bypassing any security measure.
 
4) Acknowledge the responses you receive, good or bad.
 
5) Cross-promotion of, or links to, forums competitive to this forum in 
signatures are prohibited. 

 
NOTE : Don't ever post personal or confidential data in a workbook. Forum 
owners 
and members are not responsible for any loss.
 
------------------------------------------------------------------------------------------------------

To post to this group, send email to excel-macros@googlegroups.com

-- 
FORUM RULES (986+ members already BANNED for violation)

1) Use concise, accurate thread titles. Poor thread titles, like Please Help, 
Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get 
quick attention or may not be answered.

2) Don't post a question in the thread of another member.

3) Don't post questions regarding breaking or bypassing any security measure.

4) Acknowledge the responses you receive, good or bad.

5)  Cross-promotion of, or links to, forums competitive to this forum in 
signatures are prohibited. 

NOTE  : Don't ever post personal or confidential data in a workbook. Forum 
owners and members are not responsible for any loss.

------------------------------------------------------------------------------------------------------
To post to this group, send email to excel-macros@googlegroups.com

Reply via email to