Excel VBA Scripting Dictionary Output Issue

mekueny

New Member
Joined
Feb 26, 2019
Messages
2
In VBA I have created a scripting dictionary called finDict that contains ~72k keys and items. I'm trying to write the list of keys to a worksheet.

The code below correctly prints all of the keys in finDict, but it is extremely slow:

For Z = 1 To finDict.Count
ActiveWorkbook.Sheets("Test").Range("A" & Z) = finDict.Keys(Z - 1)
Next Z

I tried replacing that code with the code below, but for some reason this code replaces most of the printed keys with "#N/A":

ActiveWorkbook.Sheets("Test").Cells(1, 1).Resize(finDict.Count) = Application.Transpose(finDict.Keys)

Can anyone spot what the issue is??
 

Some videos you may like

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.

Leith Ross

Well-known Member
Joined
Mar 17, 2008
Messages
1,874
Office Version
  1. 2010
  2. 2007
Platform
  1. Windows
Hello mekueny,

Transpose has a cutoff off 8192 distinct range areas. It is much faster to load the values into a 2-D array then output the array to the range. Here is an example...
Code:
Sub Macro2()


    Dim Dict    As Object
    Dim k       As Long
    Dim Key     As Variant
    Dim Keys    As Variant
    
        Set finDict = CreateObject("Scripting.Dictionary")
        
        ' // Code to load the dictionary goes here
        
        ReDim Keys(1 To Dict.Count, 1 To 1)
        
        For Each Key In Dict.Keys
            k = k + 1
            Keys(k, 1) = Key
        Next Key
        
        ActiveWorkbook.Sheets("Test").Range("A1").Resize(finDict.Count, 1).Value = Keys
        
End Sub
 

Akuini

Well-known Member
Joined
Feb 1, 2016
Messages
2,575
Office Version
  1. 365
Platform
  1. Windows
Transpose is limited to 65,536 elements, see this discussion:
https://www.mrexcel.com/forum/excel-questions/555073-limitation-range-size-transpose-function.html

A work around:

Code:
[FONT=lucida console][COLOR=Royalblue]Dim[/COLOR] x, va
[COLOR=Royalblue]Dim[/COLOR] i [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Long[/COLOR]

[COLOR=Royalblue]ReDim[/COLOR] va([COLOR=crimson]1[/COLOR] [COLOR=Royalblue]To[/COLOR] finDict.count, [COLOR=crimson]1[/COLOR] [COLOR=Royalblue]To[/COLOR] [COLOR=crimson]1[/COLOR])
    [COLOR=Royalblue]For[/COLOR] [COLOR=Royalblue]Each[/COLOR] x [COLOR=Royalblue]In[/COLOR] finDict.Keys
        i = i + [COLOR=crimson]1[/COLOR]
        va(i, [COLOR=crimson]1[/COLOR]) = x
    [COLOR=Royalblue]Next[/COLOR]
ActiveWorkbook.Sheets([COLOR=brown]"Test"[/COLOR]).Cells([COLOR=crimson]1[/COLOR], [COLOR=crimson]1[/COLOR]).Resize(finDict.count) = va[/FONT]

Edited: Ah, Leith Ross already got the answer.:)
 
Last edited:

Akuini

Well-known Member
Joined
Feb 1, 2016
Messages
2,575
Office Version
  1. 365
Platform
  1. Windows
You're welcome, glad to help, & thanks for the feedback.:)
 

Watch MrExcel Video

Forum statistics

Threads
1,109,425
Messages
5,528,688
Members
409,830
Latest member
KT50

This Week's Hot Topics

  • Change military grades into rank
    Afternoon all Need help with formula that will change military rank (i.e. 1, 2, 3 into Amn, A1C, SrA). Running IF formula that does not work...
  • VBA COUNTIF SOLUTION
    Hi The following are the errors spread across the several columns from E to Q ie. 13 columns across several sheets with more than 500 rows per...
  • INSERT ROW WITH SPECIFIS TEXT IN A COLUMN
    Hi All! How can identify that that the row to be inserted has to be inserted before 1st row with specific text in column F. If I record the...
  • Auto-Create a monthly Sign in sheet for preschool students
    The image below is what each page looks like. Above is space for the "Child Name" "Month" "Class" School days are obviously Monday-Friday but...
  • VBA vlookup multiple results
    Hi folks, Hopefully someone out there can help. I have a list to vlookup which works (ish). the lookup only picks up the first instance of the...
  • Extract values for earliest/latest times
    I am trying to put together a formula to get the earliest start time, the latest end time from column A for each person in Column B-F without the...
Top