Writing collection to sheet seems slow.

Certified

Board Regular
Joined
Jan 24, 2012
Messages
189
Hi,

I have a 2 dimension collection. The collections has 7 rows and 25 columns.

Writing this collection to a sheet takes about 60 seconds, which is slow to me.

The calculations are set to manual, and the displays, events and screenupdaing are set to false.

What else could be causing the code to run slow. The excel file is pretty busy with a lot of sheets and pivot tables (12.777 kb). Could the size of the file cause the code to run slow?


Code:
                        SECS1 = Timer()
                    
                    For i = 1 To theCollection.COUNT
                    
                        rowNumber = i + 10
                    
                        With Sheet17
                        
                            .Cells(rowNumber, 1) = theCollection.item(i).debtType
                            .Cells(rowNumber, 2) = theCollection.item(i).account
                            .Cells(rowNumber, 3) = theCollection.item(i).companyCode
                            .Cells(rowNumber, 4) = theCollection.item(i).investment
                            .Cells(rowNumber, 5) = theCollection.item(i).scheduleContact
                            .Cells(rowNumber, 6) = theCollection.item(i).loanDescriptions
                            .Cells(rowNumber, 7) = theCollection.item(i).maturityDate
                            .Cells(rowNumber, 8) = theCollection.item(i).currency_
                            .Cells(rowNumber, 9) = theCollection.item(i).interestRates
                            .Cells(rowNumber, 10) = theCollection.item(i).InterestExpense
                            .Cells(rowNumber, 11) = theCollection.item(i).interestPaid
                            .Cells(rowNumber, 12) = theCollection.item(i).M110
                            .Cells(rowNumber, 13) = theCollection.item(i).M210
                            .Cells(rowNumber, 14) = theCollection.item(i).M220
                            .Cells(rowNumber, 15) = theCollection.item(i).M225
                            .Cells(rowNumber, 16) = theCollection.item(i).M310
                            .Cells(rowNumber, 17) = theCollection.item(i).M350
                            .Cells(rowNumber, 18) = theCollection.item(i).M500
                            .Cells(rowNumber, 19) = theCollection.item(i).M510
                            .Cells(rowNumber, 20) = theCollection.item(i).M520
                            .Cells(rowNumber, 21) = theCollection.item(i).M521
                            .Cells(rowNumber, 22) = theCollection.item(i).M530
                            .Cells(rowNumber, 23) = theCollection.item(i).M540
                            .Cells(rowNumber, 24) = theCollection.item(i).M541
                            .Cells(rowNumber, 25) = theCollection.item(i).M799
                            
                        End With
                    
                    Next i
                    
                    SECS2 = Timer()
                    
                    Debug.Print SECS2 - SECS1

Any ideas?
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Try this:

Code:
Sub test1()
Dim MyOutput() As Variant


        SECS1 = Timer()
        ReDim MyOutput(1 To theCollection.Count, 1 To 25)
                    
        For i = 1 To theCollection.Count
                        
            MyOutput(i, 1) = theCollection.Item(i).debtType
            MyOutput(i, 2) = theCollection.Item(i).account
            MyOutput(i, 3) = theCollection.Item(i).companyCode
            
            ' etc.
            
            MyOutput(i, 24) = theCollection.Item(i).M541
            MyOutput(i, 25) = theCollection.Item(i).M799
                    
        Next i
        
        Sheet17.Range("A11").Resize(theCollection.Count, 25).Value = MyOutput
                    
        SECS2 = Timer()
                    
        Debug.Print SECS2 - SECS1
End Sub

Writing to a worksheet is one of the slowest things you can do in Excel, and you do it 175 times. It's much faster to save everything in an internal VBA array, then write the entire array in one statement.
 
Last edited:
Upvote 0
Approx the same, but for the mentioned rowNumber = i + 10
Rich (BB code):
  SECS1 = Timer()

  Dim a()
  ReDim a(1 To 1, 1 To 25)
  
  SECS1 = Timer()
  
  For i = 1 To theCollection.Count
    With theCollection.Item(i)
      a(1, 1) = .debtType
      a(1, 2) = .account
      a(1, 3) = .companyCode
      a(1, 4) = .investment
      a(1, 5) = .scheduleContact
      a(1, 6) = .loanDescriptions
      a(1, 7) = .maturityDate
      a(1, 8) = .currency_
      a(1, 9) = .interestRates
      a(1, 10) = .InterestExpense
      a(1, 11) = .interestPaid
      a(1, 12) = .M110
      a(1, 13) = .M210
      a(1, 14) = .M220
      a(1, 15) = .M225
      a(1, 16) = .M310
      a(1, 17) = .M350
      a(1, 18) = .M500
      a(1, 19) = .M510
      a(1, 20) = .M520
      a(1, 21) = .M521
      a(1, 22) = .M530
      a(1, 23) = .M540
      a(1, 24) = .M541
      a(1, 25) = .M799
    End With
    rowNumber = i + 10
    Sheet17.Cells(rowNumber, 1).Resize(, 25).Value = a()
  Next

  SECS2 = Timer()
  Debug.Print SECS2 - SECS1
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,818
Messages
6,181,152
Members
453,021
Latest member
Justyna P

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