+ Reply to Thread
Results 1 to 11 of 11

matching 8 cells to their counterparts

  1. #1
    Forum Contributor
    Join Date
    06-09-2009
    Location
    Wales
    MS-Off Ver
    Excel 2003
    Posts
    155

    Question matching 8 cells to their counterparts

    Hi,

    I have a table which is 8 columns wide by approximately 1000 (+) rows. I am struggling with the following;

    if I type in seven numbers somewhere I need to get returns on a full 8 cell match? (and possible partial, but exact matches to 4+out of 8 numbers) All the numbers in individual cells are no larger than 99 and (in theory) are arranged from left to right in ascending order.

    Can anyone point me in the right direction?

    I don't want to use auto filter as I am just looking for a reference that I am searching the correct number. Does that make sense?

    I have as advised below now added an attachment.

    Cheers

    Si.
    Attached Files Attached Files
    Last edited by opsman; 06-15-2009 at 04:49 PM. Reason: adding attachment

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

    Re: matching 8 cells to their counterparts

    To best describe or illustrate your problem you would be better off attaching a dummy workbook, the workbook should contain the same structure and some dummy data of the same type as the type you have in your real workbook - so, if a cell contains numbers & letters in this format abc-123 then that should be reflected in the dummy workbook.

    If needed supply a before and after sheet in the workbook so the person helping you can see what you are trying to achieve.

    Doing this will ensure you get the result you need!

  3. #3
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: matching 8 cells to their counterparts

    Doing this will ensure you get the result you need
    !
    possibly
    "Unless otherwise stated all my comments are directed at OP"

    Mojito connoisseur and now happily retired
    where does code go ?
    look here
    how to insert code

    how to enter array formula

    why use -- in sumproduct
    recommended reading
    wiki Mojito

    how to say no convincingly

    most important thing you need
    Martin Wilson: SPV
    and RSMBC

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

    Re: matching 8 cells to their counterparts

    hey - it's not me - it's a canned response

  5. #5
    Forum Contributor
    Join Date
    06-09-2009
    Location
    Wales
    MS-Off Ver
    Excel 2003
    Posts
    155

    Question Re: matching 8 cells to their counterparts

    I have now made up a quick dummy file and attached it to the original post.

    Si.

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

    Re: matching 8 cells to their counterparts

    Apologies for delay in response.

    My instinct would be to use a column adjacent to the data rows to ease the process of filtering the results... using your example file:

    L2: =SUMPRODUCT(COUNTIF($B2:$I2,$B$28:$I$28))+(ROWS(L$2:L2)/1000)
    copied down

    In terms of listing the results - exact/close I would list all in one dataset but use the value in L to ensure that the data is listed in order of closeness in desc order... ie closest matches first.

    Let's say then (again using your sample) that we hold in C31 the count of records to be returned...

    C31: =COUNTIF($L$2:$L$12,">1")

    Then I can populate the table of results as follows

    A35: =IF(ROWS(A$35:A35)>$C$31,"",MOD(LARGE($L$2:$L$12,ROWS(A$35:A35)),1)*1000)
    copied down as far as required.

    B35:
    =IF(ISNUMBER($A35),INDEX(B$2:B$12,$A35)*(COUNTIF($B$28:$I$28,INDEX(B$2:B$12,$A35))>0),"")
    copied across and down as far as required (ie across numbers matrix - up to and incl. column H)
    To hide the 0's apply a custom format to this range of: #;;

    J35:
    =IF(ISNUMBER($A35),INDEX($J$2:$J$12,$A35),"")
    copied down as far as required

    So you should then find that using your sample if you begin to add a close match in row 4 the results table updates as you enter the values - resorting the data so closest is listed first etc...
    Last edited by DonkeyOte; 06-15-2009 at 06:40 AM.

  7. #7
    Forum Contributor
    Join Date
    06-09-2009
    Location
    Wales
    MS-Off Ver
    Excel 2003
    Posts
    155

    Re: matching 8 cells to their counterparts

    No problem,

    It make take a few moments to get my head around as I've only recently become addicted to excel!!

    In the mean time many thanks, I'll let you know how I get on....

    Simon

  8. #8
    Forum Contributor
    Join Date
    06-09-2009
    Location
    Wales
    MS-Off Ver
    Excel 2003
    Posts
    155

    Re: matching 8 cells to their counterparts

    Donkey OTE

    OK....should I start or finish with the words....Faaanblooodytastic!!!!

    I think I get the logic, but what is in my head doesn't compute to what's in your formula... can you explain the formula for L2, I think I can work through it from there?

    Secondly, and not wishing to irritate you after being unbelievably helpful, I got a circular reference error which I got around by changing the iteration, will that slow the function down?

    Finally, I put some random numbers in the table before considering moving it to the main file and was quite shocked with the high ammount of returns I got. Is there anyway of limiting it for example to the higher half of returns or for 4 or 5+ matches only??

    I look forward to hearing from you and many many many thanks for your help.

    Simon

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

    Re: matching 8 cells to their counterparts

    Quote Originally Posted by opsman View Post
    I think I get the logic, but what is in my head doesn't compute to what's in your formula... can you explain the formula for L2, I think I can work through it from there?
    The formula essentially conducts a COUNTIF for each value in a given row against the predetermined range of 8 values... it SUMS the results... then to that result it adds the row number being processed / 1000 such that each value listed in L is unique ... ie if you had 2 rows containing 5 matches you can distinguish between the two sets of values via the use of ROW... no 2 in L values will be the same (assumes you have less than 1000 rows of data... if you have more than that increase the divisor such that the ROW/divisor is always less than 1, a safe divisor may be 1000000)

    Quote Originally Posted by opsman
    Secondly, and not wishing to irritate you after being unbelievably helpful, I got a circular reference error which I got around by changing the iteration, will that slow the function down?
    Not sure how you're generating circulars... you may need to post an example.

    Quote Originally Posted by opsman
    Finally, I put some random numbers in the table before considering moving it to the main file and was quite shocked with the high ammount of returns I got. Is there anyway of limiting it for example to the higher half of returns or for 4 or 5+ matches only??
    Yes, simply change C31 COUNTIF criteria from >1 to say >=4 etc... where the 4 dictates the min. count of matches required to be listed
    Last edited by DonkeyOte; 06-15-2009 at 04:11 PM. Reason: amended final sentence

  10. #10
    Forum Contributor
    Join Date
    06-09-2009
    Location
    Wales
    MS-Off Ver
    Excel 2003
    Posts
    155

    Re: matching 8 cells to their counterparts

    Well, many thanks not only for your quick response but for being so helpful!

    Perhaps the circular error was something to do with how I mucked around with the formulas. When I first copied it I had not copied across the $ on the L2 formula, so when I dragged it across the cells on the sample I had to go back and manually ammend the references. That was about the time the error cam into play....so maybe that's the simple answer?

    I'll pluck up the courage to enter it into the master later and keep my fingers crossed and my back ups backed up!! lool....

    Now I need to work out how to post glowing feedback, do you have a formula?

    Cheers & hope the weather is better in suffolk than in North Wales!

    Regards

    Simon

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

    Re: matching 8 cells to their counterparts

    Quote Originally Posted by opsman View Post
    .. hope the weather is better in suffolk than in North Wales!
    Unless you're drowning, no, not presently!
    (I'm not drowning incidentally - it's just raining, hard...)
    Last edited by DonkeyOte; 06-15-2009 at 05:03 PM.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

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