+ Reply to Thread
Results 1 to 5 of 5

Lookup Column Header based on cell value

  1. #1
    Registered User
    Join Date
    02-22-2007
    Posts
    10

    Lookup Column Header based on cell value

    Hi,

    Hoping to tap into your collective experience to help me with this! I have a spreadsheet an excerpt of which is as follows:

    K L M N
    1 Doors Security Vehicle Key
    2 TRUE FALSE FALSE FALSE
    3 FALSE TRUE TRUE FALSE
    4 FALSE FALSE FALSE FALSE

    Want I want to happen is to return the column header where there for a cell which contains "TRUE" in a blank column. If there isn't a cell with the value "TRUE" then to return "N/A". In the above example in blank column P for Row 2 would be "Doors", Row 3 would be "Security,Vehicle" and Row 4 would be "N/A".

    In my actual spreadsheet I have 12 columns (L to W) which have the TRUE or FALSE values.

    I know it has something to do with either HLOOKUP, INDEX and MATCH but can't seem to get it right. Any ideas?
    Last edited by kingcal; 08-13-2009 at 03:56 AM.

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

    Re: Lookup Column Header based on cell value

    =Index($L$1:W$1,Match(True,$L2:$W2,0)) copied down.
    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.

  3. #3
    Registered User
    Join Date
    02-22-2007
    Posts
    10

    Re: Lookup Column Header based on cell value

    Excellent. Thanks very much for that - it returns an accurate result for about 90% of the rows but not for those where there are more than one "TRUE" value in the row, e.g.

    K L M N
    1 Doors Security Vehicle Key
    2 FALSE TRUE TRUE FALSE

    The formula above only returns the first column header where there is a "TRUE" value but not the second (or any other) column headers, so in the example above it would only return Security but not Vehicle. Is there anyway that all of the appropriate column headers could be seperated by a comma e.g. "Security, Vehicle"?

    Many thanks for your help.

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

    Re: Lookup Column Header based on cell value

    The easiest way is with the help of an addin or udf function....

    If you want an addin, try this free addin that include many more useful functions..it's called Morefunc.xll and can be downloaded from here:


    Then apply this formula:

    =SUBSTITUTE(TRIM(MCONCAT(IF($L2:$W2=TRUE,$L$1:W$11,"")," "))," ",", ")

    confirmed with CTRL+SHIFT+ENTER, not just ENTER and copied down.

    Or you can apply this popular UDF:

    Please Login or Register  to view this content.
    and then apply formula:

    =SUBSTITUTE(TRIM(aconcatT(IF($L2:$W2=TRUE,$L$1:W$11,"")," "))," ",", ")

    again, confirmed with CTRL+SHIFT+ENTER and copied down.

  5. #5
    Registered User
    Join Date
    02-22-2007
    Posts
    10

    Re: Lookup Column Header based on cell value

    Cheers, many thanks - worked like a dream!

+ 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