Excel VBA with Solver Solutions

Orbit

New Member
Joined
May 18, 2014
Messages
24
So here is my issue. I am trying to write a loop that performs a function using solver. Basically it starts in one cell, runs solver, moves the target and constraint cells to the right one, solves, moves target and contraint cells to the right 14, solves, right one, solves, right 14 solves, until it finds a blank.
Here is the first few lines of code to show you what I am doing in the long version, but I would like to write it in a loop so that if I need to make edits, it does not take as long. My main issue is how to get the cells to move properly.
<code style="margin: 0px; padding: 0px; border: 0px; font-family: Consolas, Menlo, Monaco, 'Lucida Console', 'Liberation Mono', 'DejaVu Sans Mono', 'Bitstream Vera Sans Mono', 'Courier New', monospace, sans-serif; white-space: inherit;">Range("RI6").Select
SolverOk SetCell
:="$RI$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$RG$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$RI$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$RI$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("RJ16").Select
SolverOk SetCell
:="$RJ$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$RJ$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$RJ$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$RJ$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("RX16").Select
SolverOk SetCell
:="$RX$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$RX$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$RX$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$RX$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("RY16").Select
SolverOk SetCell
:="$RY$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$RY$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$RY$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$RY$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("SM16").Select
SolverOk SetCell
:="$SM$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$SM$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$SM$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$SM$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("SN16").Select
SolverOk SetCell
:="$SN$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$SN$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$SN$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$SN$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("TB16").Select
SolverOk SetCell
:="$TB$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$TB$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$TB$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$TB$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("TC16").Select
SolverOk SetCell
:="$TC$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$TC$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$TC$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$TC$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("TQ16").Select
SolverOk SetCell
:="$TQ$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$TQ$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$TQ$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$TQ$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("TR16").Select
SolverOk SetCell
:="$TR$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$TR$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$TR$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$TR$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("UF16").Select
SolverOk SetCell
:="$UF$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$UF$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$UF$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$UF$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)
Range
("UG16").Select
SolverOk SetCell
:="$UG$16", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$UG$1", _
Engine
:=1, EngineDesc:="GRG Nonlinear"
SolverAdd CellRef
:="$UG$1", Relation:=3, FormulaText:="74"
SolverAdd CellRef
:="$UG$1", Relation:=1, FormulaText:="87"
SolverSolve
(True)

</code>Thank you in advance for any help / advice.
 
Last edited:

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.
This is not tested on your code, but I've done similar things in the past. It should at least show you how to change the ranges. I also recommend using the SolverReset function, otherwise every succeeding Solve will try to use previously defined constraints.

Code:
MyCol = 477   ' Column RI

While Cells(16, MyCol) <> ""
    SolverReset
    SolverOk SetCell:=Cells(16, MyCol), MaxMinVal:=3, ValueOf:=0.15, ByChange:=Cells(16, MyCol), _
        Engine:=1, EngineDesc:="GRG Nonlinear"
    SolverAdd CellRef:=Cells(MyCol, 1), Relation:=3, FormulaText:="74"
    SolverAdd CellRef:=Cells(MyCol, 1), Relation:=1, FormulaText:="87"
    SolverSolve (True)

    SolverReset
    SolverOk SetCell:=Cells(16, MyCol + 1), MaxMinVal:=3, ValueOf:=0.15, ByChange:=Cells(16, MyCol + 1), _
        Engine:=1, EngineDesc:="GRG Nonlinear"
    SolverAdd CellRef:=Cells(1, MyCol + 1), Relation:=3, FormulaText:="74"
    SolverAdd CellRef:=Cells(1, MyCol + 1), Relation:=1, FormulaText:="87"
    SolverSolve (True)

    MyCol = MyCol + 14
Wend
 
Upvote 0
Thank you. I only had to make a minor adjustment to the code in order to get it to work with my sheet.

I really appreciate the help.
 
Upvote 0

Forum statistics

Threads
1,213,524
Messages
6,114,117
Members
448,549
Latest member
brianhfield

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