Forum Discussion

Lost_inExcel's avatar
Lost_inExcel
Copper Contributor
May 09, 2024

Finding the best combination of values using solver

Question: How do I use Excel built in solver to get the correct combination?

Objective: To purchase parts at lowest cost.

Constraints: Divvy up among 3 suppliers/out of 5 suppliers ; a total of 19 parts in some combination.

A solution could look like this:

Sup1-->P1,P4,P7,P19,P16
Sup2-->P2,P5,P8,P15,P13,P17,P18
Sup3-->P3,P6,P9,P10,P11,P12,P14

 

Input data as follows:

SupplierPart numberCost
Sup1P1$10.00
Sup1P2$9.00
Sup1P3$5.00
Sup1P4$6.00
Sup1P5$6.00
Sup1P6$15.00
Sup1P7$11.00
Sup1P8$8.00
Sup1P9$71.00
Sup1P10$11.00
Sup1P11$12.00
Sup1P12$21.00
Sup1P13$22.00
Sup1P14$6.00
Sup1P15$31.00
Sup1P16$6.00
Sup1P17$4.00
Sup1P18$17.00
Sup1P19$8.00
Sup2P1$6.00
Sup2P2$8.00
Sup2P3$11.00
Sup2P4$4.00
Sup2P5$8.00
Sup2P6$34.00
Sup2P7$12.00
Sup2P8$8.00
Sup2P9$55.00
Sup2P10$77.00
Sup2P11$13.00
Sup2P12$25.00
Sup2P13$23.00
Sup2P14$2.00
Sup2P15$34.00
Sup2P16$12.00
Sup2P17$3.00
Sup2P18$13.00
Sup2P19$7.00
Sup3P1$9.00
Sup3P2$11.00
Sup3P3$4.00
Sup3P4$3.00
Sup3P5$2.00
Sup3P6$23.00
Sup3P7$13.00
Sup3P8$8.00
Sup3P9$45.00
Sup3P10$29.00
Sup3P11$14.00
Sup3P12$23.00
Sup3P13$24.00
Sup3P14$3.00
Sup3P15$49.00
Sup3P16$16.00
Sup3P17$1.00
Sup3P18$12.00
Sup3P19$6.00
Sup4P1$8.00
Sup4P2$13.00
Sup4P3$2.00
Sup4P4$7.00
Sup4P5$8.00
Sup4P6$55.00
Sup4P7$14.00
Sup4P8$8.00
Sup4P9$48.00
Sup4P10$34.00
Sup4P11$15.00
Sup4P12$22.00
Sup4P13$25.00
Sup4P14$8.00
Sup4P15$32.00
Sup4P16$13.00
Sup4P17$2.00
Sup4P18$11.00
Sup4P19$5.00
Sup5P1$9.00
Sup5P2$12.00
Sup5P3$1.00
Sup5P4$16.00
Sup5P5$1.00
Sup5P6$41.00
Sup5P7$15.00
Sup5P8$8.00
Sup5P9$26.00
Sup5P10$67.00
Sup5P11$16.00
Sup5P12$17.00
Sup5P13$26.00
Sup5P14$7.00
Sup5P15$22.00
Sup5P16$12.00
Sup5P17$5.00
Sup5P18$19.00
Sup5P19$4.00
  • djclements's avatar
    djclements
    May 11, 2024

    Lost_inExcel I'm not entirely sure, without seeing what went wrong. If you could save and attach the file (or provide a screenshot), I could possibly offer something more concrete. What version of Excel are you using? The formulas I used will only work with Excel for MS365. This is what it looks like when I input $1 for all parts for Sup1:

     

    Min Cost via Data Table

     

    As long as you input any Row_ID with the lowest cost (1 thru 6) in cell F13, it should assign all 19 parts to Sup1.

  • Lost_inExcel 

    The attached works by exhaustive search.

    =LET(
        distinct,       UNIQUE(part),
        supplierH,      TOROW(UNIQUE(supplier)),
        costArray,      MINIFS(cost, part, distinct, supplier, supplierH),
        combinations,   CombinationsĪ»(N, m),
        totalCosts,     BYROW(
            combinations,
            LAMBDA(combin, SUM(BYROW(FILTER(costArray, combin), MIN)))
        ),
        selected,       XLOOKUP(MIN(totalCosts), totalCosts, combinations),
        filtered,       FILTER(costArray, selected),
        bestCost,       BYROW(filtered, MIN),
        partBySupplier, IF(filtered = bestCost, distinct, ""),
        partList,       TOCOL(BYCOL(partBySupplier, LAMBDA(p, TEXTJOIN(", ", , p)))),
        return,         VSTACK(
            HSTACK("Best cost:", SUM(bestCost)),
            HSTACK(TOCOL(FILTER(supplierH, selected)), partList)
        ),
        CHOOSE(line, distinct, supplierH, costArray, combinations, totalCosts, selected, filtered, bestCost, partBySupplier, partList, return)
    )

    Just for fun, the workbook allows you to step through the formula line by line

      • PeterBartholomew1's avatar
        PeterBartholomew1
        Silver Contributor

        djclements 

        I have wondered about asking Microsoft for a function such as RETURN( ) or even IN( ) to close the local naming scope and return the contents of any variable by index (mod n) with zero as the default.

         

        Looking at your solution, I realised that it represents the first time I have ever made a data table work (I messed up with selecting the range first time round so then had to reinstate the solution).  It will most likely be the first and last time because now, for better or worse, I am almost certain to define the calculation as a Lambda function and use MAP to generate the output list.

         

        As a further point of interest, you may be interested in a workbook I posted in another discussion that uses SCAN and thunks to generate combinations.  The method is mind twistingly complicated but is reasonably efficient.  The calculation of 924 combinations corresponding to 12C6 took 3.5ms rather than 27ms required for a 'brute force approach.

      • PeterBartholomew1's avatar
        PeterBartholomew1
        Silver Contributor

        Lost_inExcel 

        That is odd.  This is what I get

        It appears to be a problem with the Lambda function CombinationsĪ»

        CombinationsĪ»
        = LAMBDA(n, m,
            LET(
                binary, BASE(SEQUENCE(2 ^ n), 2, n),
                bits, --MID(binary, SEQUENCE(1, n), 1),
                criterion, BYROW(VALUE(bits), SUM) = m,
                FILTER(bits, criterion)
            )
        );

        It is a brute force approach that starts with any number of objects taken from N and only then filters for the m objects required.  Now as I look, I think the problem is that I have used an eta-reduced Lambda function and you are not using the insiders beta version of Excel.  Either switching to insiders channel or introducing an anonymous Lambda function to perform the summation by row should work

        CombinationsĪ»
        = LAMBDA(n, m,
            LET(
                binary,    BASE(SEQUENCE(2 ^ n), 2, n),
                bits,    --MID(binary, SEQUENCE(1, n), 1),
                criterion, BYROW(VALUE(bits), LAMBDA(x, SUM(x))) = m,
                FILTER(bits, criterion)
            )
        );

        Sorry about setting traps for you :sad:.  

  • NikolinoDE's avatar
    NikolinoDE
    Gold Contributor

    Lost_inExcel 

    To use Excel's Solver tool to find the best combination of values for purchasing parts at the lowest cost, follow these steps:

    1. Set Up Your Worksheet:
      • Enter the supplier names, part numbers, and costs into your Excel worksheet as shown in your input data.
    2. Define Your Variables:
      • Create a table to represent the quantities of each part purchased from each supplier. Each cell in the table will represent the quantity of a specific part purchased from a specific supplier. You can vary these quantities to minimize the total cost.
      • Define the decision variables (quantities) in your Solver model. These will be the cells in your worksheet that represent the quantities of parts purchased.
    3. Define the Objective Function:
      • Determine the objective function that you want to minimize. In this case, you want to minimize the total cost of purchasing the parts. The total cost can be calculated by summing the product of each part's quantity and its corresponding cost.
      • Create a formula in a cell to calculate the total cost based on the quantities of parts purchased and their costs.
    4. Set Up Constraints:
      • Define any constraints that need to be satisfied. In this case, you want to ensure that the total quantity of parts purchased from each supplier does not exceed the total available quantity of parts, and that each part quantity is non-negative.
      • Create formulas or use Excel functions to set up these constraints in your worksheet.
    5. Run Solver:
      • Open the Solver tool in Excel. You can find it under the "Data" or "Analysis" tab, depending on your version of Excel.
      • Set up Solver to minimize the objective function subject to the defined constraints.
      • Specify the decision variables, objective function, and constraints in the Solver Parameters dialog box.
      • Run Solver to find the optimal solution.
    6. Review the Results:
      • Once Solver has finished running, review the results to see the optimal quantities of parts to purchase from each supplier that minimize the total cost.
      • Solver will adjust the quantities in the decision variable cells to achieve the optimal solution.

    By following these steps and using Excel's Solver tool, you can find the best combination of values to minimize the cost of purchasing parts from multiple suppliers while satisfying any constraints you may have. The text and steps were edited with the help of AI.

     

    My answers are voluntary and without guarantee!

     

    Hope this will help you.

    Was the answer useful? Mark as best response and Like it!

    This will help all forum participants.

  • djclements's avatar
    djclements
    Bronze Contributor

    Lost_inExcel I was able to solve this with Excel for MS365 using array functions and a Data Table. The first step was to generate a list of all possible combinations of 3 suppliers out of 5 using a custom LAMBDA function (PERMA). The second step was to create a MINIFS-based summary report to calculate the minimum cost for the first combination of suppliers using the Row_ID as a single input variable. The third step was to use a Data Table (Data > What-If Analysis > Data Table...) to generate the minimum costs for all combinations of suppliers (for every Row_ID variable) and identify the combination with the lowest total cost. Lastly, the results of the combination with the lowest total cost were filtered to generate the desired output.

     

    Min Cost via Data Table

     

    Please see the attached workbook to view all of the formulas used to generate the final results...

     

    Additional resources:

    • Lost_inExcel's avatar
      Lost_inExcel
      Copper Contributor

      djclements 

       

      Thank you very much! Calculation is good.

      Had question if :

      I artificially put $1/- for each part for Sup1, the by default, it does not assign 19 parts to supplier1.

      Why would that be the case

      • djclements's avatar
        djclements
        Bronze Contributor

        Lost_inExcel I'm not entirely sure, without seeing what went wrong. If you could save and attach the file (or provide a screenshot), I could possibly offer something more concrete. What version of Excel are you using? The formulas I used will only work with Excel for MS365. This is what it looks like when I input $1 for all parts for Sup1:

         

        Min Cost via Data Table

         

        As long as you input any Row_ID with the lowest cost (1 thru 6) in cell F13, it should assign all 19 parts to Sup1.

Resources