+ Reply to Thread
Results 1 to 10 of 10

Excel solver macro

  1. #1
    Registered User
    Join Date
    01-05-2011
    Location
    Slovenia
    MS-Off Ver
    Excel 2016
    Posts
    49

    Excel solver macro

    Hi

    I have a large document, that need to be calculated with excel solver. I record a macro and now i have problem, because each scenarios (based on dates in C6) have a different number of rows that need to be calculated with solver.


    i need a macro that will automatical change variable cells and also range of constraint based on cell range in T4:Z44 and constraints range ab4:af44. So solver will calculate only cells with values in.


    Example

    date 1: 31.7.2017 show data in table range T4:Z14
    changing variable cell are set from X4:X13
    constraint are:
    AD4:AD10<=20
    W45=C5
    X4:X13 <= 20
    X4:X13 >= 5


    macro for that part is written and it is in attachement file
    Please Login or Register  to view this content.


    but if i change date in cell C6 to 4.9.2017 i have data in range T4: Z16. And macro that i'm lookin for will change variable cells from previus to current range of cell,
    for example changing variable cell will be X4:X16
    constraint will be:
    AD4:AD10<=20
    W45=C5
    X4:X16 <= 20
    X4:X16 >= 5

    any suggestion ?
    Attached Files Attached Files

  2. #2
    Forum Expert Alf's Avatar
    Join Date
    03-13-2004
    Location
    Gothenburg/Mullsjoe, Sweden
    MS-Off Ver
    Excel 2019 and not sure I like it
    Posts
    4,758

    Re: Excel solver macro

    Assuming that you first select the date you could perhaps use something like this:

    Please Login or Register  to view this content.
    The calculation of i assumes that there are no blank cells in the range X4 to X & i. I would recommend that you add the line "SolverReset" at the start of the solver macro as this clears all old
    in data from solver.

    As a recording of a solver setup adds repetitive lines of solver commands I've deleted these. And you only need to add what engine you wish to use i.e. "Engine:=1", or "EngineDesc:="GRG Nonlinear" not both of them as a recorded macro will do.

    Then you need to set up the constraint you mentioned above.

    Alf

  3. #3
    Registered User
    Join Date
    01-05-2011
    Location
    Slovenia
    MS-Off Ver
    Excel 2016
    Posts
    49

    Re: Excel solver macro

    Thanks for reply.

    I'm not sure if I understand this, while I get message from solver ''The Objective Cell values do not converge''. I'm quite new with solver programming

    Process is in that order:
    1) i select date in C6
    2 and based on that date there is large list of cells in range T4:Z? . Formulas are in the background, and show values which belong to certain date. And that values are calculated by solver. Every scenario has different range of rows (14 rows, 16 rows, 10 rows,....)

    3) Macro adjust changing variable cells to to the line with last full row. X4:X14 then if next date have more rows to X4:X16,....
    and same with constraint

    4) Macro run the solver and show results.


    In attached file there is working solver model. It work manualy or by macro but just for this selected date. If I change date and that date have different range of rows, then i have to manualy change variable cells and same with constraint. I need macro that will automaticaly change range based on data in cells

  4. #4
    Forum Expert Alf's Avatar
    Join Date
    03-13-2004
    Location
    Gothenburg/Mullsjoe, Sweden
    MS-Off Ver
    Excel 2019 and not sure I like it
    Posts
    4,758

    Re: Excel solver macro

    Well here is a modified macro that works for me :

    Please Login or Register  to view this content.
    One of the problems was finding the right range (last row) for solver to work on. Normal technique did work as formulas in cells that evaluated to blanks was counted as data so I had to use a work around.

    As there are a number of macros in this file I don't know what macro depends on another so result could be strange but my Slovenian is not good enough to sort this out. Running the macro using the date 2017-09-04 and testing using 2017-07-31 I got numbers in X14 to X16 as the previous run had 16 rows of data. I did delete the values in X14:X16 before doing the 2017-07-31 run.

    Alf
    Last edited by Alf; 07-16-2018 at 07:05 AM.

  5. #5
    Registered User
    Join Date
    01-05-2011
    Location
    Slovenia
    MS-Off Ver
    Excel 2016
    Posts
    49

    Re: Excel solver macro

    Thanks it works but i think there is only one detail that is missing

    sometimes i get this message ''Solver encountered an error value in the objective cell or a constraint cell'' - i think i get this message because there is also constraint in range AD4:AD? and that constraint also have to change everytime - find last row and modify it in constraint list in solver like ''changing variable cell'' in code above

    SolverAdd CellRef:="$AD$4:$AD$10" -> macro has to change that part too by finding last row in range $AD$4:$AD$ ?

    How to add this ?

    and one question - if i add some more constraint in the future, what is the easiest way to add constraints as code in macro ? I'm asking this because your code is quite different from the one I got while I recorded a macro


    sorry because model is in my language, but this is large file and translation everything would be quite challenge. In column T i have plant name and in columns besides there are some economic values. In column AB there are associated botanic family and one part of optimization in AB section is about limitation of total ussage of certain botanic families ex. Brassicaceae

  6. #6
    Forum Expert Alf's Avatar
    Join Date
    03-13-2004
    Location
    Gothenburg/Mullsjoe, Sweden
    MS-Off Ver
    Excel 2019 and not sure I like it
    Posts
    4,758

    Re: Excel solver macro

    Please Login or Register  to view this content.
    Use the same technique as I used in the macro to set the X4:X?? range and use another letter say j to be dimmed as an Integer. And this constraint needs to be set when the solver model is build by the macro the same way as the range X4:X? is set up

    if i add some more constraint in the future, what is the easiest way to add constraints as code in macro ?
    Just write it in as a "SolverAdd CellRef:=" line where you add a relation i.e.

    Please Login or Register  to view this content.
    tells solver that the range X4:X? should be equal to or less 20. Relation:=2 means equal to and Relation:=3 means equal to or greater than a specified value. Relation:=4, FormulaText:="integer" sets the result in that specified range to integers and Relation:=5, FormulaText:="binary" sets the result to the specified range to binary values.

    You can also specify a range

    Please Login or Register  to view this content.
    were the result values in E12:G12 should be equal to or less than the values in E11:G11

    Testing the model a bit more I also got the ''Solver encountered an error value in the objective cell or a constraint cell', but part of the problem seems to be some underlying calculation so I pressed F9 to get excel to calculate the workbook and ded a solver rerun and that did work.

    What seems to be important is that the range X4:X? should be equal to or less than the T4:T? range if it's greater you do get some funny results in the AD column. Could be fixed in the macro by adding this line.

    Please Login or Register  to view this content.
    or you do it manually.

    sorry because model is in my language,
    Don't worry, this was more a bit of a warning that since I do not understand the language I could not work out how things interacted so it could be my macro made a mess of resuts elsewhere as there are quite a number of macros in your uploaded file.

    Alf

  7. #7
    Registered User
    Join Date
    01-05-2011
    Location
    Slovenia
    MS-Off Ver
    Excel 2016
    Posts
    49

    Re: Excel solver macro

    Thank you for explanation. it helps me to understand how this works

    What seems to be important is that the range X4:X? should be equal to or less than the T4:T? range if it's greater you do get some funny results in the AD column. Could be fixed in the macro by adding this line.
    Yes, whole range from column T:Z have same number of rows. allways

    Please Login or Register  to view this content.

    This is what i have right now, but still doesent work quite i imagined. Sometimes it leave last few rows blank ? But it works when I manually adjust in solver menu.

    I think the main problem is with AD4:AD ? If macro could adjust last row in the solver constraint, then it would work perfectly. Same thing as in X column

  8. #8
    Forum Expert Alf's Avatar
    Join Date
    03-13-2004
    Location
    Gothenburg/Mullsjoe, Sweden
    MS-Off Ver
    Excel 2019 and not sure I like it
    Posts
    4,758

    Re: Excel solver macro

    Your macro is not right i.e. you need to change the order of a line and having calculated a value for j it should be used in the AD constraint. Not sure why you used the AB rang in the calculation of j.

    I changed that to AD but if that's wrong you change it back to AB.

    Please Login or Register  to view this content.
    Alf

  9. #9
    Registered User
    Join Date
    01-05-2011
    Location
    Slovenia
    MS-Off Ver
    Excel 2016
    Posts
    49

    Re: Excel solver macro

    Thank you so much. This is it

  10. #10
    Forum Expert Alf's Avatar
    Join Date
    03-13-2004
    Location
    Gothenburg/Mullsjoe, Sweden
    MS-Off Ver
    Excel 2019 and not sure I like it
    Posts
    4,758

    Re: Excel solver macro

    You are welcome.

    Thanks for feedback and rep

    Alf

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Replies: 0
    Last Post: 07-20-2014, 12:45 PM
  2. macro not keeping solver solutions when solver is successful
    By jimmypants in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 06-10-2014, 01:45 AM
  3. Solver Foundation Excel Macro
    By mayorofarta in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 01-01-2013, 06:22 AM
  4. solver macro + simulation code + not updating solver values
    By sabinemaria in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 07-24-2012, 11:37 AM
  5. Excel Macro for running solver
    By kodamv in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 01-11-2009, 04:21 PM
  6. How to record macro for Solver in Excel?
    By Samirkc in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 11-22-2005, 01:10 AM
  7. Interacting with EXCEL Solver via macro
    By Dean in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 01-26-2005, 09:06 AM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1