Peltier Technical Services, Inc.
 

Excel Chart Add-Ins | Training | Charts and Tutorials | Peltier Tech Blog


Peltier Tech Chart Utility

 

Using Solver in Excel VBA

Contents
Solver and Conventional VBA
Avoiding Solver Reference Problems
Preparing Solver for First Use
Solver Links

Solver and Conventional VBA

Solver is a powerful analysis tool, bundled with Excel and used for optimization and simulation of business and engineering models. It can be even more powerful if used in conjunction with VBA, to automate solving of multiple models which use different input parameters and constraints.

In a simple example, there are two factors in B5 and B6. The product (=B5*B6) is calculated in B8. Solver will be used to find the maximum value of the target cell (the product in B8), subject to the constraint that both factors (B5:B6) shall not exceed a value of 4. Select Solver from the Tools menu, and enter the appropriate conditions and constraints in the Solver Parameters dialog.

Click the Solve button, and another dialog indicates whether a solution is found and offers some options.

If you record a macro while you use Solver, you will get something like the following:

Sub SolverMacro1()
'
' SolverMacro1 Macro
' Macro recorded by Jon Peltier
'
    SolverOk SetCell:="$B$8", MaxMinVal:=1, ValueOf:="0", ByChange:="$B$5:$B$6"
    SolverAdd CellRef:="$B$5:$B$6", Relation:=1, FormulaText:="4"
    SolverOk SetCell:="$B$8", MaxMinVal:=1, ValueOf:="0", ByChange:="$B$5:$B$6"
    SolverSolve
End Sub

SolverAdd adds constraints to the Solver model. SolverOK defines the cell to optimize, how to optimize it, and what cells to change during the Solver optimization. The macro recorder wrote this line twice, so the first occurrence can be removed. To prevent parameters from a different Solver optimization interfering with the macro's optimization, Solver should be reset prior to running, using SolverReset. SolverSolve has an optional UserFinish argument; if UserFinish is False or omitted, the second dialog shown above will ask the user whether to save the optimization, but if UserFinish is True, Solver will end without the dialog. A modified Solver macro is shown below:

Sub SolverMacro2()
'
' SolverMacro2 Macro
' Macro fixed up by Jon Peltier
'
    SolverReset
    SolverAdd CellRef:="$B$5:$B$6", Relation:=1, FormulaText:="4"
    SolverOk SetCell:="$B$8", MaxMinVal:=1, ValueOf:="0", ByChange:="$B$5:$B$6"
    SolverSolve True
End Sub

When you try to run this macro, you get a compile error. The command SolverReset is highlighted, and the following error message appears.

In order to use a macro based on an installed add-in, you must first make sure that the add-in is installed, then you must set a reference to the add-in in the workbook containing the code that calls the add-in's procedures.

To install an add-in, on Excel's Tools menu, choose Add-Ins. If the add-in is shown on the list, check the box in front of its name. If the add-in is not found, click Browse, navigate to the add-in file*, then when it appears on the add-in list, check its checkbox. Solver was already installed, or we would not have been able to record a macro using it.

*Depending on your Office and Windows versions, the default Excel add-ins library is "C:\Program Files\Microsoft Office\OFFICE15\Library" or "C:\Documents and Settings\{username}\Application Data\Microsoft\AddIns". By default in Excel 2013, Solver is located in "C:\Program Files\Microsoft Office\OFFICE15\Library\SOLVER".

     

To set a reference to an add-in, it must first be installed. Then on the VB Editor's Tools menu, select References. This lists all open workbooks and installed add-ins, as well as a huge list of resources installed on the host computer. Find the add-in in the list, and check the box in front of its name.

     

With a reference set to Solver, SolverMacro2 will run as expected. In addition, the Solver library will be accessible through the VB Editor's Object Browser (right), and you will have the benefit of Intellisense (below) while editing code that uses members of the Solver library.

    


 


Avoiding Solver Reference Problems

The code you write to run Solver will work on your computer, and on any computer with the same versions of Excel and Solver. In fact, it should work on any computer that has later versions of Excel and Solver. If you want to distribute your workbook with VBA code written for Solver, you should write the code using the earliest expected version of Excel, so it will work on all versions that users may have installed. When the workbook is first opened on a given computer, it finds the references resources, or more recent versions if available.

This sounds easy, but sometimes it isn't. Perhaps you developed a workbook in Excel 2013 for your department to use, but you have to send it to a supplier, and the supplier hasn't upgraded past Excel 2007. Or perhaps the workbook must be shared amongst a group of users who have different versions of Excel and Solver installed. In these cases, a computer with an earlier version of Solver installed will choke on the reference to a later version of Solver.

It is possible, of course, to install add-ins and set references using VBA. This can be tricky, the user has to grant permission for VBA code to access any VB projects. Without this permission, references to installed components cannot be set.

To avoid issues with installing add-ins and setting references to various resources, your code can be modified so that it is called using Application.Run. Without a reference to the add-in, you lose IntelliSense and the Object Browser, and your code suffers from a small (probably imperceptible) performance penalty. However, you gain simpler, more reliable execution. The syntax is straightforward: Application.Run is followed by the procedure name in double quotes, followed by a comma separated list of arguments being passed to the procedure:

Application.Run "SubName", Argument1, Argument2,...

If Application.Run is used to return the calculated result of a function, the syntax is slightly different, with a variable set equal to Application.Run, with the procedure and arguments enclosed within parentheses:

MyVariable = Application.Run("Function", Argument1, Argument2,...)

The SolverMacro2 procedure above is easily modified to use Application.Run:

Sub SolverMacro3()
'
' SolverMacro3 Macro
' Macro fixed up by Jon Peltier
' Edited to use Application.Run to avoid reference problems
'
    Application.Run "SolverReset"
    Application.Run "SolverAdd", "$B$5:$B$6", 1, "4"
    Application.Run "SolverOk", "$B$8", 1, "0", "$B$5:$B$6"
    Application.Run "SolverSolve", True
End Sub

A more general version of a Solver procedure is shown below. This includes more informative comments, and it provides a notice to the user about the success of the Solver optimization. Note that before Excel 2007, the name of the solver add-in was "Solver.xla", not "Solver.xlam".

Sub RunSolver()
  '' Adjusted for Application.Run() to avoid Reference problems with Solver 
  '' Peltier Technical Services, Inc., Copyright © 2007. All rights reserved.

  ' reset
  Application.Run "Solver.xlam!SolverReset"

  ' set up new analysis
  Application.Run "Solver.xlam!SolverOk", "Blah1", 1, , "BlahBlah1"

  ' add constraints
  Application.Run "Solver.xlam!SolverAdd", "Blah2", 3, 0
  Application.Run "Solver.xlam!SolverAdd", "Blah3", 2, "BlahBlah3"

  ' run the analysis
  Result = Application.Run("Solver.xlam!SolverSolve", True)

  ' finish the analysis
  Application.Run "Solver.xlam!SolverFinish"

  ' report on success of analysis
  If Result <= 3 Then
    ' Result = 0, Solution found, optimality and constraints satisfied
    ' Result = 1, Converged, constraints satisfied
    ' Result = 2, Cannot improve, constraints satisfied
    ' Result = 3, Stopped at maximum iterations
    MsgBox "Solver found a solution", vbInformation, "SOLUTION FOUND"
  Else
    ' Result = 4, Solver did not converge
    ' Result = 5, No feasible solution
    Beep
    MsgBox "Solver was unable to find a solution.", vbExclamation, "SOLUTION NOT FOUND"
  End If

End Sub

The results of the SolverSolve function include:

      0  Solver found a solution. All constraints and optimality conditions are satisfied. 
      1  Solver has converged to the current solution. All constraints are satisfied. 
      2  Solver cannot improve the current solution. All constraints are satisfied. 
      3  Stop chosen when the maximum iteration limit was reached. 
      4  The Set Cell values do not converge. 
      5  Solver could not find a feasible solution. 
      6  Solver stopped at user's request. 
      7  The conditions for Assume Linear Model are not satisfied. 
      8  The problem is too large for Solver to handle. 
      9  Solver encountered an error value in a target or constraint cell. 
     10  Stop chosen when maximum time limit was reached. 
     11  There is not enough memory available to solve the problem. 
     12  Another Excel instance is using SOLVER.DLL. Try again later. 
     13  Error in model. Please verify that all cells and constraints are valid. 

Preparing Solver for First Use

One frequent complaint about automating Solver is that it doesn't work using VBA until it has been used at least once manually. This is because Solver installs itself in a kind of "on demand" mode. Unlike a regularly-installed add-in, it is not opened until it is first used. And until it is first used, it hasn't run its Auto_Open procedure, which is what actually prepares it to run. Using VBA you can bypass the initial manual Solver operation with this command:

Application.Run "Solver.xlam!Solver.Solver2.Auto_open"

This command should be run before the first Solver optimization procedure is executed. I have developed a Solver initialization routine that first makes sure the computer even has Solver, then it installs it and runs its Auto_Open procedure. The procedure is written as a function, which returns True if Solver is available and ready to use. I usually call this procedure from the parent workbook's Workbook_Open event procedure. If CheckSolver is False, I usually have the workbook close itself after a brief warning to the user.

Function CheckSolver() As Boolean
  '' Adjusted for Application.Run() to avoid Reference problems with Solver 
  '' Peltier Technical Services, Inc., Copyright © 2007. All rights reserved.
  '' Returns True if Solver can be used, False if not.

  Dim bSolverInstalled As Boolean

  '' Assume true unless otherwise
  CheckSolver = True

  On Error Resume Next
  ' check whether Solver is installed
  bSolverInstalled = Application.AddIns("Solver Add-In").Installed
  Err.Clear

  If bSolverInstalled Then
    ' uninstall temporarily
    Application.AddIns("Solver Add-In").Installed = False
    ' check whether Solver is installed (should be false)
    bSolverInstalled = Application.AddIns("Solver Add-In").Installed
  End If

  If Not bSolverInstalled Then
    ' (re)install Solver 
    Application.AddIns("Solver Add-In").Installed = True
    ' check whether Solver is installed (should be true)
    bSolverInstalled = Application.AddIns("Solver Add-In").Installed
  End If

  If Not bSolverInstalled Then
    MsgBox "Solver not found. This workbook will not work.", vbCritical
    CheckSolver = False
  End If

  If CheckSolver Then
    ' initialize Solver 
    Application.Run "Solver.xlam!Solver.Solver2.Auto_open"
  End If

  On Error GoTo 0

End Function

The function above works fine for English versions of Excel, but in other languages, the name of the add-in may not be "Solver Add-In". We have to be a bit more clever, and introduce a loop to check the filenames of all add-ins. The CheckSolverIntl function below calls two additional functions which perform the loops. This function still relies on Solver being named "solver.xlam". If this is not the case, for example, in different language versions of Excel, change the value of the constant sAddIn in this procedure, and please email me about it.

Function CheckSolverIntl() As Boolean
  '' Adjusted for Application.Run() to avoid Reference problems with Solver
  '' Adjusted for international versions of Excel
  '' Peltier Technical Services, Inc., Copyright © 2008. All rights reserved.
  '' Returns True if Solver can be used, False if not.

  Dim bSolverInstalled As Boolean
  Dim bAddInFound As Boolean
  Dim iAddIn As Long
  Const sAddIn As String = "solver.xlam"

  '' Assume true unless otherwise
  CheckSolverIntl = True

  On Error Resume Next
  ' check whether Solver is installed
  bSolverInstalled = IsInstalled(sAddIn)
  Err.Clear

  If bSolverInstalled Then
    ' uninstall temporarily
    bAddInFound = AddInInstall(sAddIn, False)
    ' check whether Solver is installed (should be false)
    bSolverInstalled = IsInstalled(sAddIn)
  End If

  If Not bSolverInstalled Then
    ' (re)install Solver
    bAddInFound = AddInInstall(sAddIn, True)
    ' check whether Solver is installed (should be true)
    bSolverInstalled = IsInstalled(sAddIn)
  End If

  If Not bSolverInstalled Then
    MsgBox "Solver not found. This workbook will not work.", vbCritical
    CheckSolverIntl = False
  End If

  If CheckSolverIntl Then
    ' initialize Solver
    Application.Run sAddIn & "!Solver.Solver2.Auto_open"
  End If

  On Error GoTo 0

End Function

Function IsInstalled(sAddInFileName As String) As Boolean
  Dim iAddIn As Long
  
  IsInstalled = False
  
  For iAddIn = 1 To Application.AddIns.Count
    With Application.AddIns(iAddIn)
      If LCase$(.Name) = LCase$(sAddInFileName) Then
        If .Installed Then
          IsInstalled = True
        End If
        Exit For
      End If
    End With
  Next
  
End Function

Function AddInInstall(sAddInFileName As String, bInstall As Boolean) As Boolean
  Dim iAddIn As Long
  
  For iAddIn = 1 To Application.AddIns.Count
    With Application.AddIns(iAddIn)
      If LCase$(.Name) = LCase$(sAddInFileName) Then
        If .Installed <> bInstall Then
          .Installed = bInstall
        End If
        AddInInstall = True ' True = add-in is listed
        Exit For
      End If
    End With
  Next
  
End Function

Solver Links

Frontline Systems
Frontline Systems has developed Solver add-ins for Excel and other applications. The standard Excel Solver add-in can be upgraded to a premium Solver version or to other specialized Solvers, and there are versions for use with other programming platforms. While the capabilities of Solver are very extensive, the online documentation is somewhat sparse.

Microsoft

Around the Web

 

Peltier Tech Chart Utility


Peltier Technical Services, Inc.

Excel Chart Add-Ins | Training | Charts and Tutorials | PTS Blog

Peltier Technical Services, Inc., Copyright © 2014. All rights reserved.
You may link to this article or portions of it on your site, but copying is prohibited without permission of Peltier Technical Services.

Microsoft Most Valuable Professional

Microsoft Most Valuable Professional

My MVP Profile