Native VBA Multithreading

Multithreading VBA – VBA vs. VBscript vs. C#.NET


I you were looking for an end-to-end analysis of the topic of multithreading VBA. You have come to the right place! So lately I have been really wearing out the topic of multithreading in Excel in VBA. Hopefully you have already read through my three posts on the various methods of achieving multithreading capabilities in VBA:

In all three posts I showed that, although “native” VBA does not feature multithreading, you can in fact achieve multithreading by using either external COM/dlls (e.g. in C#.NET), running VBscripts via the Windows Shell command or run additional VBA worker threads via VBscript. All three approaches have their ups and downs. Now just to clarify: What do I mean by “native”? I mean that VBA as a programming language does not natively support creating new threads, joining threads etc.

Pro’s and Con’s of all multithreading VBA approaches

Let us summarize them in the table below:

Multithreading approach Pro’s Con’s
Using a C#.NET COM/dll
  • Best performance – even singlethreaded C#.NET COM/dlls will significantly reduce the execution time of your algorithms
  • Easy parallelism – C# provides the “Parallel” class which allows you to easily create and manage threads and run for loop in multiple threads
  • Requires learning C#
  • Requires referencing an external dll – must make sure it is not lost when sharing the Excel file
  • Requires a separate programming environment (e.g. Visual Studio) to create, modify and compile
VBscript worker threads
  • Fairly easy to implement
  • VBscript is almost identical with VBA language
  • Worst performance – as VBscript is much slower than native VBA in most cases multithreading your algorithms using multiple VBscript worker threads will extend execution time instead of reducing it. I would recommend using VBscript worker threads only if the threads are to leverage other system libraries/resources
VBA worker threads (via VBscript)
  • Good performance – you should see a proportional reduction of execution time, at some point, when using this approach (2 cores ~= 2x faster)
  • Most complicated – VBA worker threads run via VBscript
  • More room for errors
  • Overhead – multithreading makes sense when VBA algorithm takes at least 5 sec or more depending on the amount of cores/processors available. This is due to the overhead resulting from invoking separate VBA worker threads in separate Excel processes via VBscript

Performance: Native VBA vs. VBA workers vs. VBscript workers vs. C#.NET

I would like to warn you that these are only example metrics run on a specific environment (on a 2-core 4 threaded Intel processor (i5-4300U)). I didn’t focus too much of my time on drafting very precise metrics as these statistics are simply meant to give you the general idea of the relative performance of all approaches.
Comparison of different approaches to multithreading VBA
As you can see the VBscript parallelism approach provides very lousy performance and it gets worse the more operations the algorithm has. I know what you are thinking now: well then want is the sense of using VBscript multithreading if the performance is awful in the provided example? Well there are examples when VBscript threading makes sense see Daniel’s example here. In most common examples you should, however, disregard the VBscript approach therefore I removed it from the chart and focused on the remaining methods:

Comparison of different approaches to multithreading VBA (excluding VBscript worker threads)
As expected C#.NET rules the stats! While it took at least 26 sec to compute 900mln operations in “native” VBA, C#.NET managed to do this in less than 2 sec. On the other hand the VBA parallel workers managed to reduce the computation time to about 10 sec which is less than half the “native” VBA execution time. Still not bad – would have been much better if my CPU had more cores. Notice that the break-even point between the “native” VBA algorithm and the VBA parallel workers methods was at about 100mln operations – taking approx. 3 seconds. It seems therefore that there is a couple of seconds of overhead in case of the latter approach.

Source code and example

If you want to download the whole source code containing all these example approaches see the link at the bottom of this post. To gather these performance statistics I made a single Excel workbook that allows you to test all multithreading VBA approaches and verify which is the best fit for your algorithm / use case.
Screenshot from the Excel Workbook consolidating the findings (download link at the bottom)

VBA – No multithreading

Below you can find the a “native” VBA example of a simple division algorithm. This is the baseline for the other algorithms.

VBA – no multithreading (the baseline)

Sub VBASinglethread()
    Dim i As Long, j As Long, x As Double, startTimeS As Date, endTimeS As Date
    startTimeS = Timer
    '---Compute partition of the division table---
    For i = 1 To divTabSize
       For j = 1 To divTabSize
          x = CDbl(i) / j
       Next
    Next
    endTimeS = Timer
    elapsed = "" & Format(endTimeS - startTimeS, "0.00")
    Range("J2").Value = elapsed
    DoEvents
End Sub

 

C#.NET- Single and multithreaded

Below you can find 2 example algorithms in C#.NET. One is singlethreaded and the other one leverages the C# Parallel class to easily achieve multithreading.

C#.NET COM/dll code

using System.Linq;
using System.Runtime.InteropServices;
using System.Text;
using System.Threading;
using System.Threading.Tasks;
namespace TestLib
{
    [ComVisible(true), ClassInterface(ClassInterfaceType.AutoDual)]
    public class TestClass
    {
        
        [return: MarshalAs(UnmanagedType.SafeArray)]
        public int ParallelMethod(int divTabSize)
        {   
            Parallel.For(0, divTabSize, i =>
            {
                double x;
                for (int j = 1; j < divTabSize; j++)
                {
                    x = i / j;   
                }
            });
            return 0;
        }

        [return: MarshalAs(UnmanagedType.SafeArray)]
        public int SequentialMethod(int divTabSize)
        {
            double x;
            for (int i = 1; i < divTabSize; i++)
            {
                for (int j = 1; j < divTabSize; j++)
                {
                    x = i / j;
                }
            }
            return 0;
        }
    }

    static class UnmanagedExports
    {
        [DllExport]
        [return: MarshalAs(UnmanagedType.IDispatch)]
        static Object CreateTestClass()
        {
            return new TestClass();
        }
    }
}

 

C#.NET COM/dll code – VBA example

Declare Function CreateTestClass Lib "C:Users[PATH TO DLL]TestLib.dll" () As Object
Public Declare Sub Sleep Lib "kernel32" (ByVal dwMilliseconds As Long)
Sub CshartSequential()
    Dim startTimeS As Date, endTimeS As Date
    startTimeS = Timer
    Dim testClass As Object
    Set testClass = CreateTestClass()
    Call testClass.SequentialMethod(divTabSize)
    endTimeS = Timer
    elapsed = "" & Format(endTimeS - startTimeS, "0.00")
    Range("K2").Value = elapsed
    DoEvents
End Sub
Sub CshartParallel()
    Dim startTimeS As Date, endTimeS As Date
    startTimeS = Timer
    Dim testClass As Object
    Set testClass = CreateTestClass()
    Call testClass.ParallelMethod(divTabSize)
    endTimeS = Timer
    elapsed = "" & Format(endTimeS - startTimeS, "0.00")
    Range("L2").Value = elapsed
    DoEvents
End Sub

 

VBscript multithreading

Below the source code for multithreading using VBscript worker threads. Interesting but usually of little use due to terrible performance. See Daniel Ferry’s good example of when it is worth leveraging.

VBscript worker threads

Sub VBscriptParallel(maxThreads As Long)
    Dim thread As Long, threads As Long
    For threads = 1 To maxThreads
        ClearThreadTime
        'A simple division algorithm (a multiplication table would quickly cause overflow)
        startTime = Timer
        For thread = 1 To threads
            CreateVBScriptThread thread, threads, divTabSize
        Next thread
        CheckIfFinished threads
    Next threads
End Sub
Sub CreateVBScriptThread(threadNr As Long, maxThreads As Long, divTabSize As Long)
    Dim s As String, sFileName As String, wsh As Object
    '---Copy parameters to VBscript---
    s = s & "dim i, j, oXL, x, startTime, endTime" & vbCrLf
    s = s & "startTime = Timer" & vbCrLf
    '---Compute partition of the division table---
    s = s & "For i = " & CInt(CDbl(divTabSize) * (threadNr - 1) / maxThreads + 1) & " To " & CInt(CDbl(divTabSize) * threadNr / maxThreads) & vbCrLf
    s = s & "   For j = 1 to " & divTabSize & vbCrLf
    s = s & "      x = CDbl(i) / j" & vbCrLf
    s = s & "   Next" & vbCrLf
    s = s & "Next" & vbCrLf
    '---Save the threadNr back to your Excel file! - this is the incredible part really
    s = s & "Set oXL = GetObject(, ""Excel.Application"")" & vbCrLf
    s = s & "endTime = Timer" & vbCrLf
    s = s & "oXL.workbooks(""" & ThisWorkbook.Name & """).sheets(""Status"").Range(""" & "A" & (threadNr + 1) & """) = (endTime - startTime)"
    '---Save the VBscript file---
    sFileName = ActiveWorkbook.Path & "Thread_" & threadNr & ".vbs"
    Open sFileName For Output As #1
    Print #1, s
    Close #1
    '---Execute the VBscript file asynchronously---
    Set wsh = VBA.CreateObject("WScript.Shell")
    wsh.Run """" & sFileName & """"
    Set wsh = Nothing
End Sub
'---------Verify if finished----------
Sub CheckIfFinished(maxThreads As Long)
    Dim endTime As Double, elapsed As String
    Do Until False
        DoEvents
        If Range("A2").Value <> "" Then
            If Range("A2:A" & Range("A1").End(xlDown).Row).Count = maxThreads Then
                endTime = Timer
                elapsed = "" & Format(endTime - startTime, "0.00")
                Range("G1").Offset(maxThreads).Value = maxThreads
                Range("H1").Offset(maxThreads).Value = elapsed
                Exit Sub
            End If
        End If
        Sleep 50
    Loop
End Sub

 

VBA multithreading (via VBscript)

Below the code to a good alternative to the C#.NET COM/dll approach. It uses VBscripts just for creating separate VBA worker threads. This approach can provide satisfactory results although not as incredible as C#.NET.

VBA worker threads (via VBscript)

Sub VBAMultithread(maxThreads As Long)
    Dim thread As Long, threads As Long
    For threads = 1 To maxThreads
        ClearThreadTime
        startTime = Timer
        For thread = 1 To threads
            CreateVBAThread thread, threads, divTabSize
        Next thread
        CheckIfFinishedVBA threads
    Next threads
End Sub
Sub CreateVBAThread(threadNr As Long, maxThreads As Long, divTabSize As Long)
    Dim s As String, sFileName As String, wsh As Object, threadFileName As String
    '---Save a copy of the Excel workbook---
    threadFileName = ActiveWorkbook.Path & "Thread_" & maxThreads & "_" & threadNr & ".xls"
    Call ActiveWorkbook.SaveCopyAs(threadFileName)
    '---Save the VBscript---
    s = "Set objExcel = CreateObject(""Excel.Application"")" & vbCrLf
    s = s & "Set objWorkbook = objExcel.Workbooks.Open(""" & threadFileName & """)" & vbCrLf
    s = s & "objExcel.Application.Visible = False" & vbCrLf
    s = s & "objExcel.Application.Run ""Thread_" & maxThreads & "_" & threadNr & ".xls!RunVBAMultithread"" ," & threadNr & "," & maxThreads & "," & divTabSize & ",""" & ActiveWorkbook.Name & """" & vbCrLf
    s = s & "objExcel.ActiveWorkbook.Close" & vbCrLf
    s = s & "objExcel.Application.Quit"
    '---Save the VBscript file---
    sFileName = ActiveWorkbook.Path & "Thread_" & threadNr & ".vbs"
    Open sFileName For Output As #1
    Print #1, s
    Close #1
    '---Execute the VBscript file asynchronously---
    Set wsh = VBA.CreateObject("WScript.Shell")
    wsh.Run """" & sFileName & """"
    Set wsh = Nothing
End Sub
Public Sub RunVBAMultithread(threadNr As Long, maxThreads As Long, divTabSize As Long, workbookName As String)
    'A simple division algorithm (a multiplication table would quickly cause overflow)
    Dim i As Long, j As Long, x As Double, startTimeS As Date, endTimeS As Date
    startTimeS = Timer
    '---Compute partition of the division table---
    For i = CInt(CDbl(divTabSize) * (threadNr - 1) / maxThreads + 1) To CInt(CDbl(divTabSize) * threadNr / maxThreads)
       For j = 1 To divTabSize
          x = CDbl(i) / j
       Next
    Next
    endTimeS = Timer
    elapsed = "" & Format(endTimeS - startTimeS, "0.00")
    Dim oXL
    Set oXL = GetObject(, "Excel.Application")
    oXL.Workbooks(workbookName).Sheets("Status").Range("A" & (threadNr + 1)) = elapsed
    Set oXL = Nothing
End Sub
'---------Join threads - wait until all finish and save elapsed time to worksheet----------
Sub CheckIfFinishedVBA(maxThreads As Long)
    Dim endTime As Double, elapsed As String
    Do Until False
        DoEvents
        If Range("A2").Value <> "" Then
            If Range("A2:A" & Range("A1").End(xlDown).Row).Count = maxThreads Then
                endTime = Timer
                elapsed = "" & Format(endTime - startTime, "0.00")
                Range("I1").Offset(maxThreads).Value = elapsed
                Exit Sub
            End If
        End If
        Sleep 50
    Loop
End Sub

 

Summary

Hopefully I have exhausted the topic of multithreading in VBA. I am certain there are other methods of multithreading in VBA although I would not think that it would be worth taking them into consideration. Now for the ultimate conclusions. You can leverage several approaches to VBA multithreading although each has it’s drawback and advantages. I would not eliminate any of the presented approaches as I think this depends on the algorithm you are designing / programming. I personally would almost always go with C#.NET as I am comfortable with C# and when making complex algorithms it is probably better to create them from the very beginning in a language designed to support multithreading. I understand, however, that some of my readers would prefer staying with VBA and for those I would recommend the VBA worker threads – a little more complex but still very efficient.

What do you think? What are your experiences? Did you ever had to consider multithreading in VBA?

Download

Here you can download the whole project source codes and the complete set of files:

Next steps

Check out the VBA Mulithreading Tool (the easiest way to add multithreading to Excel macro):
EXCEL: VBA Multithreading Tool
Check out the VBA Mulithreading Add-In to add multithreading to all Excel Workbooks:
EXCEL: VBA Multithreading AddIn

Want to learn how to add multithreading using C#.NET?
EXCEL: Multithreading VBA using C#.NET
Want to learn how to add multithreading using VBscript?
EXCEL: Multithreading VBA using VBscript
Want to learn how to add multithreading using VBA via VBscript?
EXCEL: Multithreading using VBA via VBscript

2 Comments

  1. Hi,

    Your work seems interesting but I’m unable to download your files.
    I get a 1ko .xlsm file that contain the following string:
    Error 403 – ForbiddenError 403 – ForbiddenYou don’t have permission to access the requested resource. Please contact the web site owner for further assistance.

    Could you please tell me how to get access to a multithreading example as some called function are missing from the published code.

    Thanks

    RPE

Leave a Reply

Your email address will not be published. Required fields are marked *

This site uses Akismet to reduce spam. Learn how your comment data is processed.