Determine optimal product mix with Solver

Applies to
Microsoft Office Excel 2003
Microsoft Excel 2000 and 2002

Book cover This article was adapted from Microsoft Excel Data Analysis and Business Modeling by Wayne L. Winston.

This classroom-style book was developed from a series of presentations by Wayne Winston, a well known statistician and business professor who specializes in creative, practical applications of Excel. So be prepared—you may need to put your thinking cap on.

Visit Microsoft Learning to buy this book.

In this article

Sample files    You can download the sample files that relate to excerpts from Microsoft Excel Data Analysis and Business Modeling from Microsoft Office Online. This article uses the files prodmix.xls and s25_1.xls through s25_5.xls.

What is the Excel Solver tool?

You use Solver when you want to find the best way to do something. Or, more formally, when you want to find the values of certain cells in a spreadsheet that optimize (maximize or minimize) a certain objective.

An optimization model has three parts: a target cell, changing cells, and constraints.

  • The target cell represents the objective or goal. For example, maximize monthly profit.
  • Changing cells are the spreadsheet cells that we can change or adjust to optimize the target cell. Fpr example, the amount of each product produced during the month.
  • Constraints are restrictions you place on the changing cells. For example, use no more resources than are available and do not produce more of a product than can be sold.

How can I determine which product mix maximizes profitability?

Companies often need to determine the monthly (or weekly) production schedule that gives the quantity of each product that must be produced. In its simplest incarnation, the product mix problem involves how to determine the amount of each product that should be produced during a month to maximize profits. Product mix must often satisfy the following constraints:

  • Product mix can't use more resources than are available.
  • There is a limited demand for each product. We can't produce more of a product during a month than is demanded because the excess production is wasted (consider a perishable drug, for example).

Let's now solve the following example of the product mix problem. You can find the solution to this problem in the file prodmix.xls (which is included in the sample files download), as shown in Figure 1.

The product mix example.

Figure 1: The product mix example.

Let's say we work for a drug company that can produce six products at their plant. Production of each product requires labor and raw material.

  • Row 4 in Figure 1 gives the hours of labor needed to produce a pound of each product, and row 5 gives the pounds of raw material needed to produce a pound of each product. For example, producing a pound of product 1 requires 6 hours of labor and 3.2 pounds of raw material.
  • For each drug, the price per pound is given in row 6, the unit cost per pound is given in row 7, and the profit contribution per pound is given in row 9. For example, product 2 sells for $11.00 per pound, incurs a unit cost of $5.70 per pound, and contributes $5.30 profit per pound.
  • This month's demand for each drug is given in row 8. For example, demand for product 3 is 1041 pounds.

This month, 4500 hours of labor and 1600 pounds of raw material are available. How can this company maximize its monthly profit?

If we knew nothing about Solver, we would attack this problem by constructing a spreadsheet in which we track for each product mix the profit and resource usage associated with the product mix. Then we would use trial and error to vary the product mix to optimize profit without using more labor or raw material than is available and without producing more of any drug than there is demand. We use Solver in this process only at the trial-and-error stage. Essentially, Solver is an optimization engine that flawlessly performs the trial-and-error search.

A key to solving the product mix problem is efficiently computing the resource usage and profit associated with any given product mix. An important tool that we can use to make this computation is the SUMPRODUCT function. The SUMPRODUCT function multiplies corresponding values in cell ranges and returns the sum of those values. Each cell range used in a SUMPRODUCT evaluation must have the same dimensions, which implies that you can use SUMPRODUCT with two rows or two columns but not with a column and a row.

As an example of how we can use the SUMPRODUCT function in our product mix example, let's try to compute our resource usage. Our labor usage is given by calculating:

(Labor used per pound of drug 1) *
(Drug 1 pounds produced) +
(Labor use d per pound of drug 2) *
(Drug 2 pounds produced) +
...
(Labor used per pound of drug 6) *
(Drug 6 pounds produced)

In our spreadsheet, we could compute labor usage (in a tedious fashion) as D2*D4+E2*E4+F2*F4+G2*G4+H2*H4+I2*I4. Similarly, raw material usage could be computed as D2*D5+E2*E5+F2*F5+G2*G5+H2*H5+I2*I5. Entering these formulas in a spreadsheet is time-consuming with six products. Imagine how long it would take if you were working with a company that produced, say, 50 products at their plant.

A much easier way to compute labor and raw material usage is to copy from D14 to D15 the formula:

SUMPRODUCT($D$2:$I$2,D4:I4)

This formula computes D2*D4+E2*E4+F2*F4+G2*G4+H2*H4+I2*I4 (which is our labor usage) and is much easier to enter!

Notice that I use the $ sign with the range D2:I2 so that when I copy the formula I still pull the product mix from row 2. The formula in cell D15 computes raw material usage.

In a similar fashion, our profit is given by calculating:

(Drug 1 profit per pound) *
(Drug 1 pounds produced) +
(Drug 2 profit  per pound) *
(Drug 2 pounds produced) +
...
(Drug 6 profit per pound) *
(Drug 6 pounds produced).

Profit is easily computed in cell D12 with the formula:

SUMPRODUCT(D9:I9,$D$2:$I$2)

We now can identity the three parts of our product mix Solver model:

Target cell Changing cells Constraints
Our goal is to maximize profit (computed in cell D12). The number of pounds produced of each product (listed in the cell range D2:I2).
  • Do not use more labor and raw material than are available. That is, the values in cells D14:D15 (resources used) must be less than or equal to the values in cells F14:F15 (the available resources).
  • Do not produce more of a drug than is in demand. That is, the values in the cells D2:I2 (pounds produced of each drug) must be less than or equal to the demand for each drug (listed in cells D8:I8).
  • We can't produce a negative amount of any drug.

How can I input this model into Solver?

I'll now show you how to input the target cell, changing cells, and constraints into Solver. Then, all you need to do is click the Solve button and Solver will find a profit-maximizing product mix!

  1. To begin, select Solver on the Tools menu. (For instructions on installing Solver, see Introduction to optimization with the Excel Solver tool.)

The Solver Parameters dialog box will appear.

The Solver Parameters dialog box.

  1. To input the target cell, click in the Set Target Cell box and then select our profit cell (cell D12). To input our changing cells, click in the By Changing Cells box and then point to the range D2:I2, which contains the pounds produced of each drug. The dialog box should now look like the following figure.

The Solver Parameters dialog box with the target cell and changing cells defined.

  1. We're now ready to add constraints to the model. Click the Add button. You'll see the Add Constraint dialog box.

The Add Constraint dialog box.

  1. To add the resource usage constraints, click in the box labeled Cell Reference and then select the range D14:D15. Choose <= from the list in the middle of the dialog box. Click in the box labeled Constraint, and then select the cell range F14:F15.

The Add Constraint dialog box with the resource usage constraints entered.

We have now ensured that when Solver tries different values for the changing cells, Solver will consider only combinations that satisfy both D14 <= F14 (labor used is less than or equal to labor available) and D15 <= F15 (raw material used is less than or equal to raw material available).

  1. Now click Add in the Add Constraint dialog box to enter the demand constraints. Simply fill in the Add Constraint dialog box as shown in the following figure.

The Add Constraint dialog box with the demand constraints entered.

Adding these constraints ensures that when Solver tries different combinations for the changing cell values, Solver will consider only combinations that satisfy the following:

  • D2 <= D8 (the amount of drug 1 made is less than or equal to the demand for drug 1)
  • E2 <= E8 (the amount of drug 2 made is less than or equal to the demand for drug 2)
  • F2 <= F8 (the amount of drug 3 made is less than or equal to the demand for drug 3)
  • G2 <= G8 (the amount of drug 4 made is less than or equal to the demand for drug 4)
  • H2 <= H8 (the amount of drug 5 made is less than or equal to the demand for drug 5)
  • I2 <= I8 (the amount of drug 6 made is less than or equal to the demand for drug 6)
  1. Click OK in the Add Constraint dialog box. The Solve Parameters dialog box should look like the following figure.

The final Solver window for the product mix problem.

  1. We enter the constraint that all changing cells be non-negative in the Solver Options dialog box, which we open by clicking the Options button in the Solver Parameters dialog box.

Solver options settings.

Select the options Assume Linear Model and Assume Non-Negative, and then click OK.

ShowWhy select these options?

Selecting the Assume Non-Negative option ensures that Solver considers only combinations of changing cells in which each changing cell assumes a non-negative value.

We selected Assume Linear Model because the product mix problem is a special type of Solver problem called a linear model. Essentially, a Solver model is linear under the following conditions:

  • The target cell is computed by adding together terms of the form (changing cell)*(constant).
  • Each constraint satisfies the linear model requirement. This means that each constraint is evaluated by adding together terms of the form (changing cell)*(constant) and comparing such sums to a constant.

Why is this Solver problem linear?

Our target cell (profit) is computed as:

(Drug 1 profit per pound) *
(Drug 1 pounds produced) +
(Drug 2 profit per pound) *
(Drug 2 pounds produced) +
...
(Drug 6 profit per pound) *
(Drug 6 pounds produced)

This computation follows a pattern in which the target cell's value is derived by adding together terms of the form (changing cell)*(constant).

Our labor constraint is evaluated by comparing the labor available to the value derived from:

(Labor used per pound of drug 1)*
(Drug 1 pounds produced) + 
(Labor used per pound of drug 2)*
(Drug 2 pounds produced) + 
...
(Labor used per pound of drug 6)*
(Drug 6 pounds produced)

Therefore, the labor constraint is evaluated by adding together terms of the form (changing cell)*(constant) and comparing such sums to a constant. Both the labor constraint and the raw material constraint satisfy the linear model requirement.

Our demand constraints take the form

(Drug 1 produced)<=(Drug 1 Demand)
(Drug 2 produced)<=(Drug 2 Demand)
...
(Drug 6 produced)<=(Drug 6 Demand)

Each demand constraint also satisfies the linear model requirement because each is evaluated by adding together terms of the form (changing cell)*(constant) and comparing such sums to a constant.

Having shown that our product mix model is a linear model, why should we care?

  • If a Solver model is linear and we select Assume Linear Model, Solver is guaranteed to find the optimal solution to the Solver model. If a Solver model is not linear, Solver may or may not find the optimal solution.
  • If a Solver model is linear and we select Assume Linear Model, Solver uses a very efficient algorithm (the simplex method) to find the model's optimal solution. If a Solver model is linear and we do not select Assume Linear Model, Solver uses a very inefficient algorithm (the GRG2 method) and might have difficulty finding the model's optimal solution.
  1. After clicking OK in the Solver Options dialog box, we're returned to the main Solver dialog box. When we click Solve, Solver calculates an optimal solution (if one exists) for our product mix model.

An optimal solution to the product mix model would be a set of changing cell values (pounds produced of each drug) that maximizes profit over the set of all feasible solutions. Again, a feasible solution is a set of changing cell values satisfying all constraints. The changing cell values shown in Figure 2 are a feasible solution because all production levels are non-negative, no production levels exceed demand, and resource usage does not exceed available resources.

A feasible solution to the product mix problem fits within constraints.

Figure 2: A feasible solution to the product mix problem fits within constraints.

The changing cell values shown in Figure 3 represent an infeasible solution for the following reasons:

  • We produce more of drug 5 than is demanded.
  • We use more labor than labor available.
  • We use more raw material than raw material available.

An infeasible solution to the product mix problem doesn’t fit within the constraints we defined.

Figure 3: An infeasible solution to the product mix problem doesn't fit within the constraints we defined.

After clicking Solve, Solver quickly finds the optimal solution shown in Figure 4. You need to select Keep Solver Solution to preserve the optimal solution values in the spreadsheet.

The optimal solution to the product mix problem.

Figure 4: The optimal solution to the product mix problem.

Our drug company can maximize its monthly profit at a level of $6,625.20 by producing 596.67 pounds of drug 4, 1084 pounds of drug 5, and none of the other drugs! We can't determine if we can achieve the maximum profit of $6,625.20 in other ways. All we can be sure of is that with our limited resources and demand, there is no way to make more than $6,625.20 this month.

Does a Solver model always have a solution?

Suppose that demand for each product must be met. We then have to change our demand constraints from D2:I2 <= D8:I8 to D2:I2 >= D8:I8. To change this constraint:

  1. Open Solver.
  2. Click the D2:I2 <= D8:I8 constraint, and then click Change.

The Change Constraint dialog box appears.

The Change Constraint dialog box.

  1. In the center box, choose >=, and then click OK.

We've now ensured that Solver will consider only changing cell values that meet all demands.

When you click Solve, you'll see the message, Solver could not find a feasible solution. This message means that with our limited resources, we can't meet demand for all products. We have not made a mistake in our model! Solver is simply telling us that if we want to meet demand for each product, we need to add more labor, more raw material, or more of both.

What does it mean if set values do not converge?

Let's see what happens if we allow unlimited demand for each product and we allow negative quantities to be produced of each drug. To find the optimal solution for this situation:

  1. Open Solver.
  2. Click the Options button, and then clear the Assume Non-Negative check box.
  3. In the Solver Parameters dialog box, click the demand constraint D2:I2 <= D8:I8, and then click Delete to remove the constraint.

When you click Solve, Solver returns the message, The Set Cell values do not converge. This message means that if the target cell is to be maximized (as in our example), there are feasible solutions with arbitrarily large target cell values. (If the target cell is to be minimized, this message means there are feasible solutions with arbitrarily small target cell values.)

In our situation, by allowing negative production of a drug, we in effect "create" resources that can be used to produce arbitrarily large amounts of other drugs. Given our unlimited demand, this allows us to make unlimited profits. In a real situation, we can't make an infinite amount of money. In short, if you see Set values do not converge, your model does have an error.

Test yourself

Solutions to these problems are provided in the files s25_1.xls through s25_5.xls, which are included in the sample files download.

  1. Suppose our drug company could buy up to 500 hours of labor at $1 per hour. Would they take advantage of this opportunity?
  2. At a chip manufacturing plant, four technicians (A, B, C, and D) produce three products (products 1, 2, and 3). The chip manufacturer can sell 80 units of product 1 this month, 50 units of product 2, and at most 50 units of product 3. Technician A can make only products 1 and 3. Technician B can make only products 1 and 2. Technician C can make only product 3. Technician D can make only product 2. For each unit produced, the products contribute the following profit: product 1, $6; product 2, $7; product 3, $10. The time (in hours) each technician needs to manufacture a product is shown in the following table.
Product Technician A Technician B Technician C Technician D
1 2 2.5 Cannot do Cannot do
2 Cannot do 3 Cannot do 3.5
3 3 Cannot do 4 Cannot do
  1. Each technician can work up to 120 hours per month. How can the chip manufacturer maximize its monthly profit?
  2. A computer manufacturing plant produces mice, keyboards, and video game joysticks. The per-unit profit, per-unit labor usage, monthly demand, and per-unit machine-time usage are given in the following table:
Mice Keyboards Joysticks
Profit/unit $8 $11 $9
Labor usage/unit .2 hour .3 hour .24 hour
Machine time/unit .04 hour .055 hour .04 hour
Monthly demand 15,000 25,000 11,000
  1. Each month, a total of 13,000 labor hours and 3,000 hours of machine time are available. How can the manufacturer maximize its monthly profit contribution from the plant?
  2. Resolve our drug example assuming a minimum demand of 200 units for each drug must be met.
  3. Jason the jeweler makes diamond bracelets, necklaces, and earrings. He wants to work at most 160 hours per month. He has 800 ounces of diamonds. The profit, labor time, and ounces of diamonds required to produce each product are given below. If demand for each product is unlimited, how can Jason maximize his profit?
Product Unit Profit Labor Hours Per Unit Ounces of Diamonds Per Unit
Bracelet $300 .35 1.2
Necklace $200 .15 .75
Earrings $100 .05 .5
 
 
Applies to:
Excel 2003