Thanks Thanks:  0
Likes Likes:  0
Results 1 to 6 of 6

Thread: Please help with formula

  1. #1
    New Member
    Join Date
    Apr 2002
    Location
    Eric
    Posts
    3
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Hello, I have been racking my brain. Any help would be greatly appreciated.
    I need a formula to caculate the following:
    The plus and minus signs are in a1 to a4 cells and I need a5 to calculate a value based on the combinations of these cells. Please see below for the values needed. Thanks for any help you can be.
    ++++ =1
    +++- =2
    ++-- =3
    +--- =4
    ---- =5
    -+++ =6
    --++ =7
    ---+ =8
    -++- =9
    --+- =10
    -+-- =11
    +--+ =12
    +-++ =13
    +-+- =14
    ++-+ =15
    -+-+ =16

  2. #2
    Board Regular
    Join Date
    Feb 2002
    Location
    Southfield,MI USA
    Posts
    2,308
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    G'day,

    Off the top of my head I'd say use a Vlookup. Basically just make that table of 16 choices somewhere like you listed above then use a formula similar to:

    =VLOOKUP(A1&A2&A3&A4,$Y$1:$Z$16,2,0)

    (where Y1:Z16 contains your table out of view).

    Hope that helps. -maybe someone has a more interesting.

    Adam

    Adam

  3. #3
    Board Regular
    Join Date
    Feb 2002
    Location
    Southfield,MI USA
    Posts
    2,308
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    ..man I can't control my grammar.

    that was meant to read..."maybe someone has a more interesting way".

    Adam reduntant

  4. #4
    Board Regular
    Join Date
    Feb 2002
    Location
    Calgary, Alberta Canada
    Posts
    3,424
    Post Thanks / Like
    Mentioned
    1 Post(s)
    Tagged
    0 Thread(s)

    Default


    Concatenate the 4 signs say in B1
    =A1&A2&A3&A4

    Use Vlookup: I named the Lookup table rL.

    =VLOOKUP(B1,rL,2,0)


  5. #5
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    83,637
    Post Thanks / Like
    Mentioned
    33 Post(s)
    Tagged
    6 Thread(s)

    Default

    On 2002-04-22 15:14, ewtodd wrote:
    Hello, I have been racking my brain. Any help would be greatly appreciated.
    I need a formula to caculate the following:
    The plus and minus signs are in a1 to a4 cells and I need a5 to calculate a value based on the combinations of these cells. Please see below for the values needed. Thanks for any help you can be.
    ++++ =1
    +++- =2
    ++-- =3
    +--- =4
    ---- =5
    -+++ =6
    --++ =7
    ---+ =8
    -++- =9
    --+- =10
    -+-- =11
    +--+ =12
    +-++ =13
    +-+- =14
    ++-+ =15
    -+-+ =16
    I'd suggest using a different set of symbols like _ for - and X for +, because they would be easier to enter.

    Select all cells with symbols (just the first column), go to the Name Box on the Formula Bar, type SYMS, and hit enter.

    Select all cells with symbols and numbers, name the selection ALIST (from Association List) via the Name Box as above.

    Enter in A1:A4 range:

    {"++++";
    "+++-";
    "+---";
    "----"}

    In A5 enter:

    =SUMPRODUCT(N(OFFSET(ALIST,MATCH(A1:A4,SYMS,0)-1,1,1,1)))

    This gives you a total/sum of A1:A4.

    Multiplying 2 terms is easy as in:

    =VLOOKUP(B1,ALIST,2,0)*VLOOKUP(C1,ALIST,2,0)

    Aladin

    [ This Message was edited by: Aladin Akyurek on 2002-04-22 15:49 ]

  6. #6
    MrExcel MVP Jay Petrulis's Avatar
    Join Date
    Mar 2002
    Location
    Chicago, IL USA
    Posts
    2,040
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Hi,

    I understood the OP to have a single +/- symbol per cell and to figure their "value" as the concatenation like Dave Patton suggests.

    Just to see what a mess this is without VBA or a lookup table, the following formula (over 500 characters) does the job.

    =IF(AND(A1:A4="+"),1)+IF(AND(A1:A3="+",A4="-"),2)+IF(AND(A1:A2="+",A3:A4="-"),3)+IF(AND(A1="+",A2:A4="-"),4)+IF(AND(A1:A4="-"),5)+IF(AND(A1="-",A2:A4="+"),6)+IF(AND(A1:A2="-",A3:A4="+"),7)+IF(AND(A1:A3="-",A4="+"),8)+IF(AND(A1="-",A4="-",A2:A3="+"),9)+IF(AND(A1:A2="-",A4="-",A3="+"),10)+IF(AND(A1="-",A2="+",A3:A4="-"),11)+IF(AND(A1="+",A4="+",A2:A3="-"),12)+IF(AND(A1="+",A2="-",A3:A4="+"),13)+IF(AND(A1="+",A2="-",A3="+",A4="-"),14)+IF(AND(A1:A2="+",A3="-",A4="+"),15)+IF(AND(A1="-",A2="+",A3="-",A4="+"),16)

    It must be array-entered with Ctrl-Shift-Enter rather than just Enter.

    BTW, I do *NOT* recommend using this at all. Possibly someone else can determine a pattern which can be pulled from the posted table, but I can't find one I can use.

    Bye,
    Jay

Some videos you may like

User Tag List

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
  •