Closed Thread
Results 1 to 11 of 11

number anagram

Hybrid View

  1. #1
    Registered User
    Join Date
    02-21-2006
    Posts
    7

    number anagram

    in column A i have a set of numbers. in column B i have a single number that is the sum of some (not all) of the numbers in column A. i dont know what numbers from column A will equal the number in column B, nor do i know how many are added together to do so. but i do know that the number in column B is a combination of numbers from column A.


    i need to know which numbers in column A add up to the equal the number in column B.

    its very important that i find a way to do this. any help would be greatly appreciated.
    Last edited by spyshot; 02-21-2006 at 05:23 PM.

  2. #2
    Pete_UK
    Guest

    Re: number anagram

    Do you mean that you want a method of generating the number in B, or
    that you want to be able to split B up to show which numbers from
    column A are added together?

    Are the numbers in A in any particular order?

    Pete


  3. #3
    Registered User
    Join Date
    02-21-2006
    Posts
    7
    split up b to show which numbers from a are added together.

    no particular order. random

    thanks

  4. #4
    Pete_UK
    Guest

    Re: number anagram

    This is actually quite a difficult problem to solve. As a example,
    suppose you had the following numbers in column A:

    15
    12
    10
    9
    7
    4
    3

    and the value in B was 28. You could choose a "Largest Fit" algorithm,
    i.e. choose the largest available number which could be included in the
    sum.

    In this instance your first choice would be 15, then 12 but then you
    find there isn't a 1, so you would discard the 12 and choose 10 and
    then you find that 3 fitted the bill, so the answer is 15, 10 and 3.
    However, another solution could be 12, 9, 4 and 3, and with a larger
    range of numbers there could be many possible solutions.

    Suppose, now, the number in B was 26. Again you would choose 15 first,
    then 12, and then discard this, choose 10 and then discard this, choose
    9 and then discard this, choose 7 then choose 4 to arrive at the
    solution. Another solution would be 12, 7, 4 and 3.

    The largest fit algorithm would generally find the solution with the
    fewest number of additions, but the numbers in A have to be taken in
    decreasing order of magnitude for this method to work, and it is
    recursive in nature.

    Perhaps someone might be encouraged to code the method in VBA for you
    ....

    Hope this helps.

    Pete


  5. #5
    B. R.Ramachandran
    Guest

    RE: number anagram

    Hi,

    You could do this using "Solver".
    Supposing the set of numbers is in A2:A11. Enter 1 in each cell in B2 to
    B11. Place the single number in C2. Enter the following formula in some
    other cell (say C3)
    =SUMPRODUCT(A2:A11,B2:B11)-C2 and click ENTER.

    Now you are going to use the Solver (the "Solver" add-in should be installed
    for this) to find the combination of numbers in Column A whose total would be
    equal to the single number you have entered in C2. For that,
    "Tools" --> "Solver" --> in "Solver Parameters" window,

    "Set Target Cell" $C$3
    "Equal To" "Value of" 0
    "By Changing Cells" $B$2:$B$11
    "Subject to the Constraints"--> click "Add" --> enter $B2$2:$B$11, select
    "bin" from the popdown list (This would add a constraint which would read as
    "$B$2:$B$11=binary")
    Click "Solve"
    The solver would find the solution by changing some of the 1's in Column B
    to 0's. The set of Column A numbers for which Column B is 1 (and not 0) is
    the solution for your problem. If the solution is satisfactory, click "Keep
    Solver Solution". Note that if more than one solution is possible, Solver
    would find the first solution.

    To add a nice touch, maybe you can use Conditional Formatting to highlight
    the numbers in Column A for which Column B is 1.

    Regards,
    B. R. Ramachandran




    "spyshot" wrote:

    >
    > in column A i have a set of numbers. in column B i have a single number
    > that is the sum of some (not all) of the numbers in column A. i dont
    > know what numbers from column A will equal the number in column B, nor
    > do i know how many are added together to do so. but i do know that the
    > number in column B is a combination of numbers from column A.
    >
    > its very important that i find a way to do this. any help would be
    > greatly appreciated.
    >
    >
    > --
    > spyshot
    > ------------------------------------------------------------------------
    > spyshot's Profile: http://www.excelforum.com/member.php...o&userid=31781
    > View this thread: http://www.excelforum.com/showthread...hreadid=515054
    >
    >


  6. #6
    Registered User
    Join Date
    02-21-2006
    Posts
    7
    Pete_UK,

    here is an example set of numbers that i am trying to find that add up to 1029.32

    66.76
    32.73
    13.77
    275.31
    39.21
    35.92
    248.91
    6.03
    23.71
    37.64
    60.26
    79.70
    3.92
    15.89
    15.89
    5.91
    48.74
    201.29
    41.04
    139.84
    21.75
    22.66
    26.50
    132.50


    so i think it is very unlikely that there is more than one solution.

    thanks for your help!
    Last edited by spyshot; 02-22-2006 at 12:40 PM.

  7. #7
    Registered User
    Join Date
    02-21-2006
    Posts
    7
    B. R.Ramachandran ,

    thank you so much, this worked!
    i cannot thank you enough!!

    fyi. i had to use zeros in column B for it to work.

    spy
    Last edited by spyshot; 02-22-2006 at 02:36 PM.

  8. #8
    Registered User
    Join Date
    02-21-2006
    Posts
    7
    Tom Hutchins,

    thank you for your reply and help. i will try this way as well. i really appreciate everyone's help...thanks!

    spy

  9. #9
    Registered User
    Join Date
    06-12-2009
    Location
    UAE
    MS-Off Ver
    Excel 2003
    Posts
    1

    Re: number anagram

    Hello Tom,

    This is a Gr8 Solution ,I am new to Coding and macros in Excel
    But i have a Question here.
    In your Code there is an Input box to enter the Target Sum.
    Instead of Inputting the Target sum, Can we not have a loop that goes to each target sum i look for.
    yOur code works perfect on my example, but i have n number of target sums that i need to get split up for.and Entering each Target sum at the input box would be a pain if i have about 30 to 35 or more than that.Also We need to enter 0 in Column B , only then Knapsackworks.
    This is a little urgent. If you could please help me with that.

    Thanks.

  10. #10
    Tom Hutchins
    Guest

    RE: number anagram

    Here is a VBA routine I wrote which may be what you need. I wrote it in C
    originally, and later adapted it to Excel VBA.

    To run the code, you will need to add a VBA code module to your workbook and
    paste in all the code below. On the worksheet with the data, select all the
    numbers in column A (but not the whole column). Run the Knapsack routine by
    selecting Macro >> Macros from the Tools menu. In the list of available
    macros that appears, select Knapsack and click Run.

    Knapsack will prompt you for a target number. Enter your target number from
    column B. Knapsack will use recursion (and iteration) to look for
    combinations of numbers which equal the target. It will list the solutions it
    finds (if any) on a new worksheet it will add to your workbook.

    Knapsack can find multiple solutions but is not guaranteed to find every
    possible solution. Also, if your data (column A) includes more than a few
    hundred numbers, it may take a long time to complete.

    I hope this is helpful. The code:

    'Global variables for Knapsack
    Public Type RngType
    Nbr As Double 'Number in cell
    Addr As String 'Address of cell
    End Type
    Public Cellz() As RngType, Targett As Double, Kount As Currency, RngCnt As
    Long, strTarget As String
    Public Soln() As RngType, SolnCnt As Long, SolnNbr As Long, SolnRow As Long

    Sub Knapsack()
    'Calls function KS to find combinations of values within the selection that
    total the target number.
    'Current LIMITS: only finds target numbers which are positive numbers; can
    find multiple solutions,
    'but not necessarily every possible solution. Also, if the target is the sum
    of the only two numbers in the
    'selection which are smaller than the target, it may not find the solution.
    Dim c As Range, aa As Long, bb As Long, msg101 As String, Temp() As
    RngType, NegFlag As Boolean, BigFlag As Boolean
    On Error GoTo KSerr1
    'Check if the selected range has > 2 cells.
    If Selection.Count < 3 Then
    MsgBox "You must select more than 2 cells", vbExclamation, "Are you
    kidding?"
    Exit Sub
    End If
    'Get the target number from the user.
    strTarget$ = InputBox("Enter the target amount")
    If Len(strTarget$) = 0 Then Exit Sub
    Targett# = CDbl(strTarget$)
    'Load range to be checked into Cellz array. Store the address & value from
    each cell in the selected range.
    RngCnt& = -1
    For Each c In Selection
    RngCnt& = RngCnt& + 1
    ReDim Preserve Temp(RngCnt&)
    Temp(RngCnt&).Addr = c.Address
    Temp(RngCnt&).Nbr = c.Value
    Next c
    'Add one more dummy element to Cellz() to make sure last cell gets tested.
    RngCnt& = RngCnt& + 1
    ReDim Preserve Cellz(RngCnt&)
    Cellz(RngCnt&).Addr = Cellz(RngCnt& - 1).Addr
    Cellz(RngCnt&).Nbr = 0
    'See if there are any negative numbers or numbers larger than Targett# in
    Temp().
    BigFlag = False
    NegFlag = False
    For aa& = 0 To (RngCnt& - 1)
    If Temp(aa&).Nbr < 0 Then
    NegFlag = True
    ElseIf Temp(aa&).Nbr > Targett# Then
    BigFlag = True
    End If
    Next aa&
    'If both NegFlag and BigFlag are True (or False), copy all elements of
    Temp() to Cellz().
    'If Negflag is False but BigFlag is True, copy only elements that are
    smaller than Targett#.
    bb& = RngCnt& - 1
    RngCnt& = -1
    For aa& = 0 To bb&
    If (BigFlag = True) And (NegFlag = False) Then
    If (Temp(aa&).Nbr <= Targett#) And (Temp(aa&).Nbr <> 0) Then
    RngCnt& = RngCnt& + 1
    ReDim Preserve Cellz(RngCnt&)
    Cellz(RngCnt&).Addr = Temp(aa&).Addr
    Cellz(RngCnt&).Nbr = Temp(aa&).Nbr
    End If
    Else
    If Temp(aa&).Nbr <> 0 Then
    RngCnt& = RngCnt& + 1
    ReDim Preserve Cellz(RngCnt&)
    Cellz(RngCnt&).Addr = Temp(aa&).Addr
    Cellz(RngCnt&).Nbr = Temp(aa&).Nbr
    End If
    End If
    Next aa&
    'Set Kount@ and SolnNbr& to zero.
    Kount@ = 0
    SolnNbr& = 0
    'First call to KS() starts the chain of recursive calls. The For..Next loop
    starts a new chain every time
    'the previous chain returns a solution or False (no solution). Each new
    chain starts one element farther in
    'Cellz(), to ensure that a different solution, if any, will be found.
    However, this means that the first
    'element in Cellz() can only be in 1 solution, the 2nd element can only be
    in 2 solutions, etc. So, we are
    'still not finding every possible solution.
    For bb& = 0 To (RngCnt& - 1)
    SolnCnt& = -1
    If KS(Cellz(bb&).Nbr, bb& + 1) Then
    SolnNbr& = SolnNbr& + 1
    SolnCnt& = SolnCnt& + 1
    ReDim Preserve Soln(SolnCnt&)
    Soln(SolnCnt&).Addr = Cellz(bb&).Addr
    Soln(SolnCnt&).Nbr = Cellz(bb&).Nbr
    'Add a new worksheet to the current workbook at the end.
    If SolnNbr& = 1 Then
    Worksheets.Add.Move After:=Worksheets(Worksheets.Count)
    SolnRow& = 1
    Else
    'Find the last row with data in column A.
    Cells(65535, 1).Select
    Selection.End(xlUp).Select
    Selection.Offset(4, 0).Select
    SolnRow& = Selection.Row
    End If
    'Stop before hitting the last row of the worksheet & abending.
    If (SolnCnt& + SolnRow&) > 65500 Then
    MsgBox "Can't fit all the solutions on the sheet",
    vbExclamation, "Error"
    Exit Sub
    End If
    'List the elements in Soln(), which make up the solution.
    For aa& = 1 To SolnCnt&
    ActiveSheet.Cells(aa& + SolnRow& + 2, 1).Value =
    Soln(aa&).Addr
    ActiveSheet.Cells(aa& + SolnRow& + 2, 2).Value = Soln(aa&).Nbr
    'Add some headings also.
    Cells(SolnRow&, 1).Value = Targett#
    Cells(SolnRow&, 2).Value = " = Target"
    Cells(SolnRow& + 2, 1).Value = "Cell"
    Cells(SolnRow& + 2, 2).Value = "Value"
    Next aa&
    End If
    'Clear the array before the next iteration.
    ReDim Soln(0)
    Next bb&
    'Find the last row with data in column A. 4 rows down, summarize the results.
    If SolnNbr& > 0 Then
    Cells(65535, 1).Select
    Selection.End(xlUp).Select
    Selection.Offset(4, 0).Select
    Selection.Value = SolnNbr& & " solutions were found. KS function was
    called " & Kount@ & " times."
    End If
    'Tell user we are done. Summarize results.
    MsgBox SolnNbr& & " solutions were found. KS function was called " &
    Kount@ & " times.", vbInformation, "Done!"
    Exit Sub
    KSerr1:
    If Err.Number <> 0 Then
    msg101$ = "Error # " & Str(Err.Number) & " was generated by " _
    & Err.Source & Chr(13) & Err.Description
    MsgBox msg101$, , "Knapsack error", Err.HelpFile, Err.HelpContext
    End If
    End Sub

    Public Function KS(yy As Double, xx As Long) As Boolean
    'My own recursive and iterative algorithm for the classic knapsack
    programming problem.
    'yy& is the cumulative total tested against the target number in this call,
    and passed to the next call
    'increased by the next element of Cellz().
    Dim nn As Long
    'Call DoEvents so the screen can refresh, etc.
    DoEvents
    'Add 1 to Kount every time function is called.
    Kount@ = Kount@ + 1
    'Start a loop to test all remaining values of Cellz[xx] from this point in
    the solution chain.
    nn& = xx&
    Do While nn& <= RngCnt&
    If (yy# = Targett#) Then
    'Found a solution in this call! Increase Soln() and save info about the last
    element of Cellz() that was
    'tried (nn&, which should always be the same as xx& at this point in the
    function).
    SolnCnt& = SolnCnt& + 1
    ReDim Preserve Soln(SolnCnt&)
    Soln(SolnCnt&).Addr = Cellz(nn&).Addr
    Soln(SolnCnt&).Nbr = Cellz(nn&).Nbr
    'Return True to the calling function.
    KS = True
    Exit Function
    ElseIf (yy# > Targett#) Then
    'yy& in this call exceeds the target number. Return False to the calling
    function.
    KS = False
    Exit Function
    'yy& is still less than the target number. Call KS() again, adding the next
    element in Cellz() to yy&
    ElseIf (KS(yy# + Cellz(nn&).Nbr, nn& + 1)) Then
    'The call to another element of Cellz() found a successful chain. Info about
    that element of Cellz()
    'has already been saved in Soln(). Now increase Soln() and store information
    about the Cellz() element
    'in this call that is one link earlier in the solution chain.
    SolnCnt& = SolnCnt& + 1
    ReDim Preserve Soln(SolnCnt&)
    Soln(SolnCnt&).Addr = Cellz(nn&).Addr
    Soln(SolnCnt&).Nbr = Cellz(nn&).Nbr
    'Return True to the calling function.
    KS = True
    Exit Function
    End If
    nn& = nn& + 1
    Loop
    KS = False
    End Function


    "spyshot" wrote:

    >
    > in column A i have a set of numbers. in column B i have a single number
    > that is the sum of some (not all) of the numbers in column A. i dont
    > know what numbers from column A will equal the number in column B, nor
    > do i know how many are added together to do so. but i do know that the
    > number in column B is a combination of numbers from column A.
    >
    > its very important that i find a way to do this. any help would be
    > greatly appreciated.
    >
    >
    > --
    > spyshot
    > ------------------------------------------------------------------------
    > spyshot's Profile: http://www.excelforum.com/member.php...o&userid=31781
    > View this thread: http://www.excelforum.com/showthread...hreadid=515054
    >
    >


Closed 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