Formula Speed

delaneyjm

Well-known Member
Joined
Apr 22, 2009
Messages
624
I was wondering where I could find a copy of the code to show formula speeds that have been demonstrated in the podcasts from time to time.
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
I modified the code in that whitepaper a bit. Since it is my Personal Macro Workbook, I used a cell in the Personal Macro Workbook to track if this is the first or second time that I called the macro. On the second call, it reports the speed of the 2nd range relative to the first. See lines in red.


Code:
Private Declare Function getFrequency Lib "kernel32" _
Alias "QueryPerformanceFrequency" (cyFrequency As Currency) As Long
Private Declare Function getTickCount Lib "kernel32" _
Alias "QueryPerformanceCounter" (cyTickCount As Currency) As Long
'
Function MicroTimer() As Double
'

' Returns seconds.
'
    Dim cyTicks1 As Currency
    Static cyFrequency As Currency
    '
    MicroTimer = 0

' Get frequency.
    If cyFrequency = 0 Then getFrequency cyFrequency

' Get ticks.
    getTickCount cyTicks1

' Seconds
    If cyFrequency Then MicroTimer = cyTicks1 / cyFrequency
End Function

Sub RangeTimer()
    DoCalcTimer 1
End Sub
Sub SheetTimer()
    DoCalcTimer 2
End Sub
Sub RecalcTimer()
    DoCalcTimer 3
End Sub
Sub FullcalcTimer()
    DoCalcTimer 4
End Sub

Sub DoCalcTimer(jMethod As Long)
    Dim dTime As Double
    Dim dOvhd As Double
    Dim oRng As Range
    Dim oCell As Range
    Dim oArrRange As Range
    Dim sCalcType As String
    Dim lCalcSave As Long
    Dim bIterSave As Boolean
    '
    On Error GoTo Errhandl

' Initialize
    dTime = MicroTimer

    ' Save calculation settings.
    lCalcSave = Application.Calculation
    bIterSave = Application.Iteration
    If Application.Calculation <> xlCalculationManual Then
        Application.Calculation = xlCalculationManual
    End If
    Select Case jMethod
    Case 1

        ' Switch off iteration.

        If Application.Iteration <> False Then
            Application.Iteration = False
        End If
        
        ' Max is used range.

        If Selection.Count > 1000 Then
            Set oRng = Intersect(Selection, Selection.Parent.UsedRange)
        Else
            Set oRng = Selection
        End If

        ' Include array cells outside selection.

        For Each oCell In oRng
            If oCell.HasArray Then
                If oArrRange Is Nothing Then
                    Set oArrRange = oCell.CurrentArray
                End If
                If Intersect(oCell, oArrRange) Is Nothing Then
                    Set oArrRange = oCell.CurrentArray
                    Set oRng = Union(oRng, oArrRange)
                End If
            End If
        Next oCell

        sCalcType = "Calculate " & CStr(oRng.Count) & _
            " Cell(s) in Selected Range: "
    Case 2
        sCalcType = "Recalculate Sheet " & ActiveSheet.Name & ": "
    Case 3
        sCalcType = "Recalculate open workbooks: "
    Case 4
        sCalcType = "Full Calculate open workbooks: "
    End Select

' Get start time.
    dTime = MicroTimer
    Select Case jMethod
    Case 1
        If Val(Application.Version) >= 12 Then
            oRng.CalculateRowMajorOrder
        Else
            oRng.Calculate
        End If
    Case 2
        ActiveSheet.Calculate
    Case 3
        Application.Calculate
    Case 4
        Application.CalculateFull
    End Select

' Calc duration.
    dTime = MicroTimer - dTime
    On Error GoTo 0

    dTime = Round(dTime, 5)
'    MsgBox sCalcType & " " & CStr(dTime) & " Seconds", _
'        vbOKOnly + vbInformation, "CalcTimer"
        
[COLOR="Red"]    With ThisWorkbook.Worksheets(1)
        If .Cells(1, 1).Value = 1 Then
            .Cells(1, 3).Value = dTime
            .Cells(1, 4).FormulaR1C1 = "=R1C3/R1C2"
            .Cells(1, 1).Value = 2
            .Calculate
            MsgBox "Method 1: " & .Cells(1, 2).Value & vbLf & "Method 2: " & .Cells(1, 3).Value & vbLf & .Cells(1, 4).Value
        Else
            .Cells(1, 2).Value = dTime
            .Cells(1, 1).Value = 1
            MsgBox "Method 1: " & .Cells(1, 2)
        
        End If
    End With[/COLOR]
Finish:

    ' Restore calculation settings.
    If Application.Calculation <> lCalcSave Then
         Application.Calculation = lCalcSave
    End If
    If Application.Iteration <> bIterSave Then
         Application.Calculation = bIterSave
    End If
    Exit Sub
Errhandl:
    On Error GoTo 0
    MsgBox "Unable to Calculate " & sCalcType, _
        vbOKOnly + vbCritical, "CalcTimer"
    GoTo Finish
End Sub

In the podcast, my Ctrl+s is mapped to DoCalcTimer1.

Bill
 
I searched the message boards for a macro to time my workbooks. They were taking about 55 minutes to calculate. The first macro I copied didn't work. The second one worked for a while, but by the time I got to timing "areas" the macro got hung up. I couldn't get it to work. I closed my workbook, without saving it. When I relaunched everything the full calc and recalc and sheet calc worked, but the area one got hung up again.

I only know enough about macros to be dangerous. My workbook now calculates every time I choose a cell, change tabs, hide or unhide a row or column, and it is now taking 90 seconds with every recalculation. I'm think this stuff has left my calculating all messed up. I ditched the workbook that I was working with (using the macro) but it seems like there is something wrong with my computer. I can't get anything done. help!
 
I searched the message boards for a macro to time my workbooks. They were taking about 55 minutes to calculate. The first macro I copied didn't work. The second one worked for a while, but by the time I got to timing "areas" the macro got hung up. I couldn't get it to work. I closed my workbook, without saving it. When I relaunched everything the full calc and recalc and sheet calc worked, but the area one got hung up again.

I only know enough about macros to be dangerous. My workbook now calculates every time I choose a cell, change tabs, hide or unhide a row or column, and it is now taking 90 seconds with every recalculation. I'm think this stuff has left my calculating all messed up. I ditched the workbook that I was working with (using the macro) but it seems like there is something wrong with my computer. I can't get anything done. help!
Check out this site:

http://www.decisionmodels.com/

Lots of good info on efficiency.
 

Forum statistics

Threads
1,215,107
Messages
6,123,126
Members
449,097
Latest member
mlckr

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