Matrix matching function

markjohns

New Member
Joined
Jul 12, 2019
Messages
3
I created an x by y non-symmetric matrix in which, for values 1-5, "O" denotes a "preference to match". A "match" occurs only if both values reciprocate the preference (1 and 2 are a "match" because both prefer the other, while 1 and 3 are NOT a match because the preference isn't reciprocated).

12345...x
1NULLO-OO
2ONULLOOO
3O-NULL-O
4O-ONULLO
5OOOONULL
.NULL
.NULL
.NULL
yNULL

<tbody>
</tbody>

1 and 2 match
1 and 4 match
1 and 5 match
2 and 5 match
3 and 5 match
4 and 5 match
1 and 3 do NOT match
2 and 3 do NOT match
2 and 4 do NOT match
3 and 4 do NOT match

First question - Is there a "match" function that lists the unique 1x1 set of matches?
Second question - Is there an "iterative match" function that lists the unique set of matches after 'n' iterations?

For example, since 1 and 4 both match with 5, then I would like to group 1, 4, and 5. I'd like the function to apply to an x by y matrix and have matches for 1 by 1, 1 by 1 by 1, 1 by 1 by 1 by ... z iterations.
 

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
Welcome to the forum.

Interesting question. Try:


Book1
ABCDEFGHIJKLM
1123456..xMatches
21NULLO-OOO01&02
32ONULLOOO-01&04
43O-NULL-O-01&05
54O-ONULLOO02&05
65OOOONULLO03&05
7.NULL04&05
8.NULL
9.NULL
10yNULL
11
Sheet3
Cell Formulas
RangeFormula
M2{=IFERROR(TEXT(SMALL(IFERROR(IF(ROW($B$2:$G$6)$B$2:$G$6),IF($B$2:$G$6=TRANSPOSE($B$2:$G$6),(ROW($B$2:$G$6)-ROW($B$2)+1)*100+COLUMN($B$2:$G$6)-COLUMN($B$2)+1)),""),ROWS($M$2:$M2)),"00&00"),"")}
Press CTRL+SHIFT+ENTER to enter array formulas.


This seems to work with your example. However, it might be better accomplished with VBA. And your second question seems like it would absolutely require VBA. I'm not exactly sure of your requirements, but it seems like you'd like to take a subset of the rows and columns based on the results of the matches, create a smaller array then repeat until you hit some stopping condition.
 
Upvote 0
That works really well. Very neat.

12345678910
1NullO OO O 01&02
2ONullOOOOOOOO 01&04
3O Null OOOOO 01&05
4OOONullO O OO 01&07
5OOOONull OOOO 01&08
6OOOO NullO O 02&04
7 OO O NullOOO 02&05
8OO OOO Null 02&06
9O OO OO Null 02&07
10O OOOO OONull 02&08
03&05
03&06
03&07
03&09
04&05
04&09
04&10
05&06
05&07
05&08
05&10
06&09
07&09
08&09


<colgroup><col span="12"><col></colgroup><tbody>
</tbody>
Thank you. I'll post another question regarding the VBA. Really appreciate it. Cheers!
 
Upvote 0
Consider the last match of your example 8 & 9. These are matching 2 spaces, not 2 Os. Is that what you wanted, or did you only want to match Os? Also, a caveat. The table must start on A1, or B2, or C3, or D4, etc. I can also fix the formula to handle other starting cells if that's an issue.
 
Upvote 0
Ah, yes I only wanted to match Os. I think I know how to correctly edit the formula, though. Thank you.
 
Upvote 0

Forum statistics

Threads
1,214,649
Messages
6,120,732
Members
448,987
Latest member
marion_davis

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top