I would use:
Sub Macro1()
    Dim Dict_aaa, R
    Dim tStart, tStop, Elapsed, tMin, tSec, msg
    
    tStart = Timer
    Set Dict_aaa = CreateObject("Scripting.Dictionary")
    For R = 1 To ActiveSheet.UsedRange.Rows.Count
        If (ActiveSheet.Cells(R, "A").Value & "X" <> "X") Then
        If (Not Dict_aaa.Exists(ActiveSheet.Cells(R, "A").Value)) Then
                Dict_aaa.Add ActiveSheet.Cells(R, "A").Value, R
        End If
        End If
    Next R
    tStop = Timer
        TElapsed = tStop - tStart
        tMin = TElapsed \ 60
        tSec = TElapsed Mod 60
    msg = "Loaded " & Dict_aaa.Count & " unique records from " & 
ActiveSheet.UsedRange.Rows.Count
    msg = msg & Chr(13) & "in " & tMin & " minutes and " & tSec & " seconds"
    MsgBox msg
End Sub

I tested it against 135,564 records, and stored 100,200 unique values in 2 
minutes 46 seconds (using Excel 2010)

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: bpascal123 <bpascal...@gmail.com>
To: excel-macros@googlegroups.com
Sent: Mon, July 30, 2012 1:29:03 PM
Subject: $$Excel-Macros$$ Excel 2007...Experiment more than 1,048,576 values in 
a 1 dimension array

Hi, 
Following a query, I'm trying the code below and I find out that the "aaa" 
array 
is dimensionned with 1,049,574 as worksheet wsb column 1 hold 1,000 values, but 
it doesn't hold values from wsb worksheet. Is there any other way to get all 
the 
2 columns from 2 different worksheet into a scripting dictionary for processing 
unique values?

---

Sub makeData()


Dim wsa As Worksheet
Dim wsb As Worksheet
Dim ra As Range
Dim rb As Range
Dim c As Range
Dim i As Long
Dim cnt As Long


With Application
    .ScreenUpdating = False
    .Calculation = xlCalculationManual
    .DisplayAlerts = False
End With


'ThisWorkbook.Worksheets.Add(after:=Worksheets(Worksheets.Count)).Name = "MSH1"
'ThisWorkbook.Worksheets.Add(after:=Worksheets(Worksheets.Count)).Name = "MSH2"
Set wsa = ThisWorkbook.Worksheets("MSH1")
Set wsb = ThisWorkbook.Worksheets("MSH2")


cnt = wsa.Rows.Count


'Set ra = wsa.Range(wsa.Cells(1, 2), wsa.Cells(Rows.Count, 2))
Set rb = wsb.Range(wsb.Cells(1, 2), wsb.Cells(1000, 2))


i = 0
For Each c In rb
    c.Value = i
    i = i + 4
Next c


With Application
    .ScreenUpdating = True
    .Calculation = xlCalculationAutomatic
    .DisplayAlerts = True
End With


End Sub


---
Pascal Baro-- 
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
 
To unsubscribe, send a blank email to excel-macros+unsubscr...@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

To unsubscribe, send a blank email to excel-macros+unsubscr...@googlegroups.com


Reply via email to