+ Reply to Thread
Results 1 to 2 of 2

find parts of a total

  1. #1
    Jim
    Guest

    find parts of a total

    I have 60 random numbers in a column of a spreadsheet. I know that 10 of
    these numbers make up the sub total of a specific amount. If I know the
    amount of the subtotal and know that 10 numbers sum to the sub total, how can
    I have Excel extract or tell me which of the 60 random numbers sum to my sub
    total?

    Thanks, Jim

  2. #2
    Ken Wright
    Guest

    Re: find parts of a total

    If you are looking for a solution (Not necessarily the only one) to a subset
    of a group of numbers that will add up to a target number, then this can
    often be done quite simply with Solver.

    Assuming range of numbers in A1:A30, add a set of 0s in B1:B30 and in say
    B31 put

    =SUMPRODUCT(A1:A30*B1:B30)

    Now do Tools / Solver / Set Target Cell 'B31' to 'value of' and put in your
    target
    number. Then, using the range selector under the 'By Changing cells'
    section, select cells B1:B30 as the ones to change and hit enter which will
    take you back to the first dialog box. Now hit the 'Add' button, and add
    the constraint that B1:B30 must be 'bin' (Means binary as in 1 or 0, and
    it's one of the dropdowns, so just hit the arrow and select 'bin') and just
    hit Solve. You MUST ensure that in this example, when you add the 'bin'
    constraint range, you do not inadvertantly include the formula cell B31,
    else you will get an error message such as 'Binary Contsraint cell reference
    must include only adjustable cells'

    Won't do any more than single solution, but for a Finance Dept that will
    often
    suffice in this context.

    The following link, will give you a helpful tutorial at
    http://www.solver.com/stepbystep.htm
    and which walks you through an interesting scenario and explains what you
    can do with the tool.

    If you are going to look for more than one target number in the data, then
    with
    that formula in say B31, in B32 type the target number, and in B33 put
    =B32-B31.
    Now have Solver solve B33 = to 0 with the same constraints. Saves having to
    change any values in Solver that way, just type what you want in B32.

    Looks quite neat too if you format B1:B30 to a white Font and then use
    conditional formatting to highlight values in Col A where Val in Col B = 1

    --
    Regards
    Ken....................... Microsoft MVP - Excel
    Sys Spec - Win XP Pro / XL 97/00/02/03

    ----------------------------------------------------------------------------
    It's easier to beg forgiveness than ask permission :-)
    ----------------------------------------------------------------------------

    "Jim" <[email protected]> wrote in message
    news:[email protected]...
    > I have 60 random numbers in a column of a spreadsheet. I know that 10 of
    > these numbers make up the sub total of a specific amount. If I know the
    > amount of the subtotal and know that 10 numbers sum to the sub total, how

    can
    > I have Excel extract or tell me which of the 60 random numbers sum to my

    sub
    > total?
    >
    > Thanks, Jim




+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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