Returning row and column of value in 2D array, with duplicates in table

mrblister

Board Regular
Joined
Nov 20, 2016
Messages
191
Office Version
  1. 2019
Platform
  1. Windows
I have a large 2D table. The table has row and column headers. Headers are "names", so it looks like:

AmyBillCat
Amy10.50.6
Bill0.510.2
Cat0.60.21

Let's say the values are ratings (it's actually a Correl table).
I need to get a list of the (top X) highest rating-pairs in descending order (so in the above example, the list I am looking for is Amy-Cat (or Cat-Amy), then Amy-Bill (or Bill-Amy), then Cat-Bill).

But how do I do that? I can use LARGE to return a list of largest values, and I found a formula that returns row and column of a value in a table BUT it only works if there are no duplicate values in the table (but there are).
Alternatively, I tried to make it so no duplicates exist in the table by adding miniscule amounts to every value, but duplicates still occurred.

It's a pretty large table, so efficiency is a concern, although I'm definitely not picky at this point.

Any thoughts?
 
Last edited:

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Difficult with formulae especially considering big data.
VBA might help.
Try this:
VBA Code:
Sub PickPairs()
Dim lr As Long, lc As Long, r As Long, c As Long, lrw As Long, w As Long
Dim dr 'data read
Dim dw() 'datawrite
With Worksheets("Data") 'source data sheet
    lr = .Cells(.Rows.Count, "A").End(xlUp).Row
    lc = .Cells(1, .Columns.Count).End(xlToLeft).Column
    dr = .Range(.Cells(1, 1), .Cells(lr, lc)) 'presuming all data in the sheet is table
End With
lrw = (lr - 1) * (lc - 1) + 1
ReDim dw(1 To lrw, 1 To 2)
dw(1, 1) = "Values"
dw(1, 2) = "Pairs"
w = 2
For r = 2 To lr
    For c = 2 To lc
        dw(w, 1) = dr(r, c)
        dw(w, 2) = dr(r, 1) & "-" & dr(1, c)
        w = w + 1
    Next c
Next r
With Worksheets("Result") 'result sheet
    .Range("A1").Resize(lrw, 2) = dw
    .Range("A1:B" & lrw).Sort key1:=.Range("A1"), Order1:=xlAscending, Header:=xlYes
End With
End Sub
 
Upvote 0
Change the sheet names as needed.
Change table boundaries if needed.
 
Upvote 0

Forum statistics

Threads
1,214,402
Messages
6,119,299
Members
448,885
Latest member
LokiSonic

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