+ Reply to Thread
Results 1 to 5 of 5

Simplify this formula?

  1. #1
    Registered User
    Join Date
    06-10-2010
    Location
    seattle
    MS-Off Ver
    Excel 2003
    Posts
    2

    Simplify this formula?

    Is there a way to simplify this formula?

    =B8&IF(D11=1,E11,"")&IF(D12=1,E12,"")&IF(D13=1,E13,"")&IF(D14=1,E14,"")&IF(D15=1,E15,"")&IF(D16=1,E16,"")&IF(D17=1,E17,"")&IF(D18=1,E18,"")&IF(D19=1,E19,"")&IF(D20=1,E20,"")&IF(D21=1,E21,"")&IF(D24=1,E24,"")&IF(D25=1,E25,"")&IF(D26=1,E26,"")&IF(D27=1,E27,"")&IF(D28=1,E28,"")&IF(D29=1,E29,"")&IF(D29=1,E29,"")&IF(D30=1,E30,"")&IF(D31=1,E31,"")&IF(D32=1,E32,"")&IF(D33=1,E33,"")&IF(D34=1,E34,"")&IF(D35=1,E35,"")&IF(D36=1,E36,"")

  2. #2
    Banned User!
    Join Date
    10-14-2006
    Posts
    1,211

    Re: Simplify this formula?

    =b8&if(countif(d11:d27,1),vlookup(1,d11:e27,2,0),"")

  3. #3
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Simplify this formula?

    If you are trying to concatenate a bunch of results where several of the values in D11:D36 could equal 1.. then you will need a user defined function...

    Add this code to your VB Editor (ALT+F11 , then INSERT|MODULE and paste code)

    Please Login or Register  to view this content.
    Then use formula:

    =B8&ACONCAT(IF($D$11:$D$36=1,$E$11:$E$36,""))

    And confirm with CTRL+SHIFT+ENTER
    not just ENTER.

    If you only expect one of the cells to contain a 1, then:

    =B8&IF(COUNTIF(D11:D36,1)>0,VLOOKUP(1,D11:E36,2,FALSE),"")

    Entered normally with just ENTER.
    Last edited by NBVC; 06-10-2010 at 10:37 PM. Reason: typo
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  4. #4
    Registered User
    Join Date
    06-10-2010
    Location
    seattle
    MS-Off Ver
    Excel 2003
    Posts
    2

    Re: Simplify this formula?

    Thanks so much for the replies. I do indeed expect more than one cell to contain 1. I have implemented your instructions above. Upon confirming with CTRL+SHIFT+ENTER, I get an error "array formulas are not valid in merged cells".

  5. #5
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Simplify this formula?

    Arrays can not be placed in Merged Cells - most Excel developers will tell you that Merged Cells should be avoided at all costs.

    Either place the Array in a cell that is unmerged or unmerge the cells you tried to place the formula in

    (If you are merging horizontally then use Centre Across Selection instead - same visual effect without any of the issues associated with Merged areas)

+ 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