+ Reply to Thread
Results 1 to 5 of 5

Calculations slowing performance

  1. #1
    Registered User
    Join Date
    02-18-2005
    Posts
    93

    Calculations slowing performance

    Hi,
    I need to get this workbook working without it taking 13 minutes to open, close and calculate.
    Would running the calculations with a macro speed up the performance of this? I am sending you a copy with a few lines, there are actually 1250 lines on the worksheet and it takes 13 minutes to open.
    I know it needs to calculate only to the end of the data, but I don't know VBA enough to figure this out.
    thanks is advance.
    Attached Files Attached Files
    Last edited by Dreamwine59; 03-11-2010 at 07:02 PM.

  2. #2
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Calculations slowing performance

    If the actual worksheet has 1250 lines, why are you using 60000 lines in the formulas?

    How about dynamic named ranges? http://www.contextures.com/xlNames01.html
    Entia non sunt multiplicanda sine necessitate

  3. #3
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Calculations slowing performance

    I have to say even with 1250 calculations each referencing 60000 rows the performance should not be that bad - it should in fact be pretty instantaneous so I suspect there are other issues (your external VLOOKUP perhaps ?)

    Is this the only sheet in the file ?


    The below outlines some basics of improving performance but per the above I'm not sure it will prove to be that relevant.


    Regards the use of Named Ranges - it can be useful to use INDEX rather than OFFSET to create it (avoid Volatility in functions utilising the name), eg:

    Please Login or Register  to view this content.
    At which point your formula becomes:

    Please Login or Register  to view this content.

    There is an overhead in using names so if the range is relatively stable at say 1250 rows, perhaps increasing incrementally then I'd suggest persisting with a hard wired range but reducing it such that it incorporates a little excess capacity but not an excessive amount.

    Please Login or Register  to view this content.

    There are other methods which would improve performance beyond those mentioned above...

    1 - sort your data

    In this case by Col A & C (this is implied as being the case by your sample)

    sorted data invariably allows for more efficient formulae...

    Please Login or Register  to view this content.
    By sorting the data we improve performance in the above by

    a) only calculating the SUMIF once per combination of A & C (subsequent repetitions simply use the already calculated result)

    b.1) we need only conduct a SUMIF rather than a SUMIFS
    this is because by sorting the data we can quickly determine the range in which all instances of our A value are found (see MATCH)

    b.2) for the same reasons as above we're now only processing a very small subset of the range in our SUMIF (ie only the range containing our A value)


    2 - Concatenation

    If sorting the data is not viable the next best thing is to add concatenation key such that we can still dispense with SUMIFS requirement and revert to a more efficient alternative like SUMIF

    Using the sample file:

    Please Login or Register  to view this content.
    Our calculation now becomes:

    Please Login or Register  to view this content.
    Note: I'm using large ranges but performance will still be pretty quick - this is down to the way SUMIF (and other standard functions) handle the referenced range - they will generally only process the "used range" so the excess is not really an issue.

  4. #4
    Registered User
    Join Date
    02-18-2005
    Posts
    93

    Re: Calculations slowing performance

    In regards to the spreadsheet, it actually has 16,472 lines on one worksheet and 4 other worksheets with Pivot tables pulling from the data.
    I came up with some code yesterday but I still have to refresh it and I think that will hose up the spreadsheet again.
    Public Sub VendorSiteTotal()
    Dim LastRow As Long

    With Worksheets("Sheet1")
    LastRow = .Cells(Rows.Count, "A").End(xlUp).Row
    .Range("V2").Formula = "=SUMIFS($J$2:$J$6000,$A$2:$A$6000,A2,$C$2:$C$6000,C2)"
    .Range("V2").AutoFill Destination:=Range("v2:v" & LastRow)

    End With

    MsgBox "Macro is Complete", vbOKOnly + vbInformation

    End Sub
    Is the SUMIFS function the casue of the slowdown? Will running this with a macro give me better performance?
    Will incorporating a refresh in the macro help with performance?

  5. #5
    Registered User
    Join Date
    02-18-2005
    Posts
    93

    Re: Calculations slowing performance

    This is solved, the concatenation and shorter formula solved the problem
    Thanks

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1