+ Reply to Thread
Results 1 to 8 of 8

Search and IF Function combo?

  1. #1
    Registered User
    Join Date
    05-18-2010
    Location
    Staffordshire
    MS-Off Ver
    Excel 2003
    Posts
    3

    Search and IF Function combo?

    I'm having a little trouble with a formula and was wondering if anyone could help.


    The situation is as follows:

    I need to search for an exact word in colums B and D. For each ROW that the word is in, the row number should refer to two cells - one in column F and the other in column K. If the cell in column F equals the cell in column K then a value of 1 should be given, if they don't equal each other then a value of 0 should be given.
    So, if the word is in row 25, then if F25=K25 the value should be 1, else the value should be 0.
    This should be done for all rows in which the word is found and the results added together.


    I hope that makes sense (although I'm not too optimistic that I've explained it particularly well.. ;p) and if not I could provide a screenshot of the spreadsheet. Many thanks in advance for any help!
    Last edited by Sheepy; 05-20-2010 at 03:28 PM. Reason: Solved

  2. #2
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Formula help

    Sounds like a sumproduct formula:

    =SUMPRODUCT(--($B$1:$B$100="cat")+($D$1:$D$100="cat"), --($F$1:$F$100=$K$1:$K$100))
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  3. #3
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Formula help

    In case the word is found on the same row in both columns B and D, this would be a better alternate:

    =SUMPRODUCT(--(ISNUMBER(SEARCH("cat",$B$1:$B$100&$D$1:$D$100))), --($F$1:$F$100=$K$1:$K$100))

  4. #4
    Registered User
    Join Date
    05-18-2010
    Location
    Staffordshire
    MS-Off Ver
    Excel 2003
    Posts
    3

    Re: Search and IF Function combo?

    JBeaucaire, I've tried that but it doesn't seem to work, thanks for trying though it was my fault for a poor explanation :P


    Okay, first off to hopefully aide understanding of the problem I've uploaded an image of a simplified version of my spreadsheet here: http://img28.imageshack.us/img28/7910/excelm.jpg


    The problem is as follows:

    For each of the 20 letters A-T, I need to do a search (in columns B and D). For each cell the desired letter is found, the row number should be used as a constant in another formula - where the cell in column F and column K (both with the same row) will return a value of 1 if they are equal and a value of 0 if they are not equal. This should be repeated for each time the specified letter is found and summed together.


    I realise this probably sounds like rubbish, so using an example for the letter A:
    Search for A in range B4:D13. Found in cell B6, so row 6 is constant. F$6 gives value N and K$6 gives value Y, so F$6 doesn't equal K$6, so return value is 0.
    Search for A in second range B19:D28. Found in cell D21, so row 21 is constant. F$21 gives Y and K$21 gives Y, so return value is 1 since F$21 = K$21
    Adding the two returned values together gives 0+1=1




    This needs to be done for 38 different ranges for all 20 letters, so I'm sure you can appreciate how tedious it would be to calculate every value manually.. :P

    Effectively I just need a search which can provide each row number for an IF function and an addition function to add the results of the IF function, but I don't know how to do it. And rather than searching for the letter in each range, would it be able to search for EVERY value of the letter throughout the whole of columns B and D and return the row numbers for all of them (38 different rows)?

    Hopefully that the explanation makes sense, if anyone can help I would be grateful =]

  5. #5
    Forum Expert teylyn's Avatar
    Join Date
    10-28-2008
    Location
    New Zealand
    MS-Off Ver
    Excel 365 Insider Fast
    Posts
    11,372

    Re: Search and IF Function combo?

    sheepy, it would be much more helpful to have the actual spreadsheet that went into the screenshot. Also, please use the forum's facilities for file upload instead of untrusted external sites.

  6. #6
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Search and IF Function combo?

    Sheepy, the exact formula I gave you works as requested. Replace "cat" with "A" in the original formula (two places).

    Or even better, put the letter A in L1, then use this:

    =SUMPRODUCT(--($B$1:$B$100=L1)+($D$1:$D$100=L1), --($F$1:$F$100=$K$1:$K$100))

    Now you just change the letter in L1 and the results change.

  7. #7
    Registered User
    Join Date
    05-18-2010
    Location
    Staffordshire
    MS-Off Ver
    Excel 2003
    Posts
    3

    Re: Search and IF Function combo?

    Ah yes, having tried it again it does work, thanks very much =]

  8. #8
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Search and IF Function combo?

    If that takes care of your need, please click EDIT in your original post, click GO ADVANCED and set the PREFIX box to SOLVED.

+ 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