Results 1 to 5 of 5

Looking for a specific sum within a range of numbers...

This is a discussion on Looking for a specific sum within a range of numbers... within the Excel Questions forums, part of the Question Forums category; Is there a way to find out if certain cells within a range sum up to a specific number? I ...

  1. #1
    New Member
    Join Date
    May 2003
    Posts
    9

    Default Looking for a specific sum within a range of numbers...

    Is there a way to find out if certain cells within a range sum up to a specific number? I often find myself looking for a certain amount - like I've got an error for a specific dollar amount - but I have a range of entries, and any combination of those numbers could sum up to the total of the error. I've tried selecting various cells with the hopes that I can randomly pick the right ones, but that's just hit or miss, and depending on how many cells (amounts) are involved, it could be impossible. Is there a formula or add-in that can check a range of numbers to see if any combination will sum up to a specific amount? (I'm using Excel 2000) Thanks!

  2. #2
    Board Regular
    Join Date
    Jun 2002
    Location
    Perth, Australia
    Posts
    1,416

    Default Re: Looking for a specific sum within a range of numbers...

    Here' s an example from Tom Oglivy, Microsoft MVP, which uses Excel's Solver function.

    In A1:A5 put
    • 14.56
      19.51
      105.64
      100.91
      21.60

    The objective is to find which of the above numbers total to 221.11.

    1. In B1:B5 put the number 1.
    2. In B7 put: =SUMPRODUCT(A1:A5,B1:B5)
    (you should get 262.22)

    3. Go to Tools menu | Solver.
    4. In "Set Target Cell", enter $B$7.
    5. "In Equal to", click the "Value of" radio button and enter 221.11.
    6. In the "by Changing Cells" box use the mouse to select B1:B5.
    7. In "Subject to the Constants" area, click the Add button and then enter:

    B1: B5 = Bin

    8. Click OK.

    Cells B1, B3, B4 should have a 1 in them, cells B2 and B5 will show zero, cell B7 will show 221.11.

    After clicking "OK" (step 8 above) the Solver Results dialog box will appear - click OK to keep the results.

    Enhancement:
    Use Conditional Formatting to highlight the numbers in column A that sum to the target value.

    1. Select A1.
    2. Go to the Format menu | Conditional Formatting.
    3. In the "Formula is" box enter "=B1=1" (no quotes)
    4. Click the Format button and choose your formatting options.
    5. Click OK, OK.
    6. Use the Paintbrush to copy the formatting to the rest of the range.

    There is a macro solution if you prefer.

    HTH

    Mike

  3. #3
    New Member
    Join Date
    May 2003
    Posts
    9

    Default Re: Looking for a specific sum within a range of numbers...

    Thanks, that worked perfectly!

  4. #4
    Board Regular
    Join Date
    Feb 2002
    Posts
    225

    Default Re: Looking for a specific sum within a range of numbers...

    sorry to rake out this old excellent answer,

    my problem is that within 116 lines of data my target value is not possible.

    Is it possible to ask solver to find the 'nearest possible' solution - below but not more than a certain figure

    thanks in advance

    rich

  5. #5
    Board Regular
    Join Date
    Feb 2002
    Posts
    225

    Default Re: Looking for a specific sum within a range of numbers...

    bump?

    thanks

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

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


DMCA.com