Run Macro /w Solver - Keeps Returning Same Solution???

betapeg

New Member
Joined
Jun 19, 2013
Messages
35
The code is supposed to run Solver and copy the results onto another sheet. Clearly, the parameters for each iteration in Solver is different so why is Solver giving me the same solution for each iteration? I know for a fact the answer is different bc I have run this before and it didn't do this. It is also mathematically impossible. Is there something in the code I am doing wrong?

Code:
    Sheets("Variance Optimization").Select
    Range("L1").Select
    Sheets("Variance Optimization").Select
    SolverOk SetCell:="$O$15", MaxMinVal:=3, ValueOf:=0, ByChange:="$O$2:$O$11", _
        Engine:=1, EngineDesc:="GRG Nonlinear"
    SolverAdd CellRef:="$O$12", Relation:=2, FormulaText:="1"
    SolverAdd CellRef:="$O$2:$O$11", Relation:=3, FormulaText:="3%"
    SolverSolve True
    Sheets("EF Data").Select
    Range("B1:B13").Select
    Selection.Copy
    Range("D1").Select
    Selection.PasteSpecial Paste:=xlPasteAllUsingSourceTheme, Operation:=xlNone _
        , SkipBlanks:=False, Transpose:=False
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Range("D1").Select
    Application.CutCopyMode = False
    Sheets("Variance Optimization").Select
    
    Sheets("Variance Optimization").Select
    Range("L1").Select
    SolverOk SetCell:="$O$15", MaxMinVal:=3, ValueOf:=0.05, ByChange:="$O$2:$O$11" _
        , Engine:=1, EngineDesc:="GRG Nonlinear"
    SolverAdd CellRef:="$O$12", Relation:=2, FormulaText:="1"
    SolverAdd CellRef:="$O$2:$O$11", Relation:=3, FormulaText:="3%"
    SolverSolve True
    Sheets("EF Data").Select
    Range("B1:B13").Select
    Selection.Copy
    Range("E1").Select
    Selection.PasteSpecial Paste:=xlPasteAllUsingSourceTheme, Operation:=xlNone _
        , SkipBlanks:=False, Transpose:=False
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Range("E1").Select
    Application.CutCopyMode = False
    Sheets("Variance Optimization").Select
    Range("L1").Select
    
    Sheets("Variance Optimization").Select
    Range("L1").Select
    SolverOk SetCell:="$O$15", MaxMinVal:=3, ValueOf:=0.1, ByChange:="$O$2:$O$11" _
        , Engine:=1, EngineDesc:="GRG Nonlinear"
    SolverAdd CellRef:="$O$12", Relation:=2, FormulaText:="1"
    SolverAdd CellRef:="$O$2:$O$11", Relation:=3, FormulaText:="3%"
    SolverSolve True
    Sheets("EF Data").Select
    Range("B1:B13").Select
    Selection.Copy
    Range("F1").Select
    Selection.PasteSpecial Paste:=xlPasteAllUsingSourceTheme, Operation:=xlNone _
        , SkipBlanks:=False, Transpose:=False
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Range("E1").Select
    Application.CutCopyMode = False
    Sheets("Variance Optimization").Select
    Range("L1").Select
    
    Sheets("Variance Optimization").Select
    Range("L1").Select
    SolverOk SetCell:="$O$15", MaxMinVal:=3, ValueOf:=0.15, ByChange:="$O$2:$O$11" _
        , Engine:=1, EngineDesc:="GRG Nonlinear"
    SolverAdd CellRef:="$O$12", Relation:=2, FormulaText:="1"
    SolverAdd CellRef:="$O$2:$O$11", Relation:=3, FormulaText:="3%"
    SolverSolve True
    Sheets("EF Data").Select
    Range("B1:B13").Select
    Selection.Copy
    Range("G1").Select
    Selection.PasteSpecial Paste:=xlPasteAllUsingSourceTheme, Operation:=xlNone _
        , SkipBlanks:=False, Transpose:=False
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Range("E1").Select
    Application.CutCopyMode = False
    Sheets("Variance Optimization").Select
    Range("L1").Select
    
    Sheets("Variance Optimization").Select
    Range("L1").Select
    SolverOk SetCell:="$O$15", MaxMinVal:=3, ValueOf:=0.2, ByChange:="$O$2:$O$11" _
        , Engine:=1, EngineDesc:="GRG Nonlinear"
    SolverAdd CellRef:="$O$12", Relation:=2, FormulaText:="1"
    SolverAdd CellRef:="$O$2:$O$11", Relation:=3, FormulaText:="3%"
    SolverSolve True
    Sheets("EF Data").Select
    Range("B1:B13").Select
    Selection.Copy
    Range("H1").Select
    Selection.PasteSpecial Paste:=xlPasteAllUsingSourceTheme, Operation:=xlNone _
        , SkipBlanks:=False, Transpose:=False
    Selection.PasteSpecial Paste:=xlPasteValues, Operation:=xlNone, SkipBlanks _
        :=False, Transpose:=False
    Range("E1").Select
    Application.CutCopyMode = False
    Sheets("Variance Optimization").Select
    Range("L1").Select
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December
Try this:

Code:
Sub x()
    Dim rCopy       As Range
    Dim rPaste      As Range
    Dim i           As Long

    Set rCopy = Worksheets("EF Data").Range("B1:B13")
    Set rPaste = Worksheets("EF Data").Range("D1:D13")
    Sheets("Variance Optimization").Select
    SolverReset

    For i = 0 To 20 Step 5
        SolverReset
        SolverOk SetCell:="O15", _
                 MaxMinVal:=3, _
                 ValueOf:=CDbl(i) / 10, _
                 ByChange:="O2:O11", _
                 EngineDesc:="GRG Nonlinear"
        SolverAdd CellRef:="O12", Relation:=2, FormulaText:="1"
        SolverAdd CellRef:="O2:O11", Relation:=3, FormulaText:="3%"
        SolverSolve UserFinish:=True

        rCopy.Copy
        rPaste.PasteSpecial Paste:=xlPasteValues
        Set rppaste = rPaste.Offset(, 1)
    Next i
End Sub
 
Upvote 0
Typos:
Code:
Sub x()
    Dim rCopy       As Range
    Dim rPaste      As Range
    Dim i           As Long

    Set rCopy = Worksheets("EF Data").Range("B1:B13")
    Set rPaste = Worksheets("EF Data").Range("D1:D13")
    Sheets("Variance Optimization").Select

    For i = 0 To 20 Step 5
        SolverReset
        SolverOk SetCell:="O15", _
                 MaxMinVal:=3, _
                 ValueOf:=CDbl(i) / 10#, _
                 ByChange:="O2:O11", _
                 EngineDesc:="GRG Nonlinear"
        SolverAdd CellRef:="O12", Relation:=2, FormulaText:="1"
        SolverAdd CellRef:="O2:O11", Relation:=3, FormulaText:="3%"
        SolverSolve UserFinish:=True

        rCopy.Copy
        rPaste.PasteSpecial Paste:=xlPasteValues
        Set rPaste = rPaste.Offset(, 1)
    Next i
End Sub
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,659
Messages
6,126,077
Members
449,286
Latest member
Lantern

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