+ Reply to Thread
Results 1 to 3 of 3

multiple lookup with multiple match conditions

  1. #1
    Registered User
    Join Date
    05-08-2006
    Posts
    4

    multiple lookup with multiple match conditions

    hello all.

    i can't find my way through index() and match() functions to solve this out and need your help.

    A1:AD1 --> numbers 1 to 30 [A1=1 B1=2... AD1=30]
    A2:AD2 --> list of dates in a given month
    A3:AD3 --> row filled by user, any cell can be blank, have one character or more

    Is there a way to create one formula to get a list where, for example, in the same column there is the character "M" in the third row, the WEEKDAY() of the same column in the second row is 1 - 5 to return the corresponding number on the first row?

    i don't know if it was clear...

    for example, if there is one "M" in cells B3, E3, L3, P3 and V3 and if weekday() in cells B2, E2, L2, P2 and V2 i want the formula to return something like "2, 5, 12, 16, 22".

    is this possible?
    thanks in advance.

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    If you download and install the free Morefunc.dll addin from here:

    http://www.download.com/Morefunc/300...-10423159.html

    then you can use this formula:

    =SUBSTITUTE(TRIM(MCONCAT(IF((A3:AD3="M")*(WEEKDAY(A2:AD2,2)<=5),A1:AD1,"")&" "))," ",", ")

    this formula must be confirmed with CTRL+SHIFT+ENTER not just ENTER. You will see { } brackets appear around the formula.

    NOTE: This assumes you mean Monday to Friday for the weekday 1 - 5.
    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
    05-08-2006
    Posts
    4
    thank you so much for your help.
    i got a lot of inspiration from your suggestion.

    i wanted a simple solution because some of the spreadsheet users may not be able to install add-ins or... may not really understand how to do it.
    i also wanted to make it both excel and OOo compatible.

    i used =IF(AND(WEEKDAY(A2;2)<6;A3="M");A1;"") in the forth row and then
    =SUBSTITUTE(TRIM(A4&" "&B4&" "&C4&" "&D4&" "&E4&" "&F4&" "&G4&" "&H4&" "&I4&" "&J4&" "&K4&" "&L4&" "&M4&" "&N4&" "&O4&" "&P4&" "&Q4&" "&R4&" "&S4&" "&T4&" "&U4&" "&V4&" "&W4&" "&X4&" "&Y4&" "&Z4&" "&AA4&" "&AB4&" "&AC4&" "&AD4);" ";", ") to get the result

    it's just a pity i can't do it in one formula only but... oh well, it works.

    thank you very, very, very much

+ 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