How to find doubles and triples in a range of numbers

Dimi

New Member
Joined
Mar 29, 2024
Messages
2
Office Version
  1. 2021
Platform
  1. Windows
Hello to the Community,

I have an Excel file with a range of numbers (B2-F6) and I was wondering if there any functions in Excel that would help me to calculate the following:

- pairs and triplets that are most often shown together in this range, irrespective of the order,
- how many times are shown.

Also, I would like to type in a range of numbers (U2-Y2) and check if there are any pairs or triplets compared to the range of numbers B2-F6. And if there are, I would like to see them somewhere.

Please find attached an image for your convenience (the results of pairs, triplets etc. are typed manually just to give you an idea)

Thank you very much in advance for your help!
 

Attachments

  • Untitled.jpg
    Untitled.jpg
    52.3 KB · Views: 22

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type
@Dimi Welcome.
Sadly for you, no response as yet on this.
I imagine that is because it is not, in my view, something that has a simple solution. Certainly not by way of formulas.
There are many potential and actual pairs and triplets within the 5 x 5 matrix.
My first thoughts were that you would have resort to using VBA to define, establish and loop to compare such.

However, as it has been rainy day, I have messed with trying to find a formula solution.
With the aid of some 'helper' ranges I do believe that I am almost there BUT I am using Excel 365 rather than 2021.
This will likely mean that my solution is not suitable for you?
I will not unnecessarily clutter the thread with my effort unless you think it may help.

Hopefully, someone brainier than myself will be along shortly with a viable solution.
 
Upvote 1
irrespective of the order,
I'm not sure of the significance of that since every row in your sample data is sorted small to large. So I can't see how, say, 25 and 28 could be in that order in one row but 28 and 25 order in another row.
Anyway, this is my attempt at a solution, for pairs only at this stage.

VBA Code:
Sub Multiples()
  Dim d As Object
  Dim a As Variant, Ky As Variant
  Dim i As Long, j As Long, k As Long, uba2 As Long, MaxCount As Long
  Dim s As String
  
  Set d = CreateObject("Scripting.Dictionary")
  a = Range("B2:F6").Value
  uba2 = UBound(a, 2)
  For i = 1 To UBound(a)
    For j = 1 To uba2 - 1
      For k = j + 1 To uba2
        s = a(i, j) & ";" & a(i, k)
        d(s) = d(s) + 1
        If d(s) > MaxCount Then MaxCount = d(s)
      Next k
    Next j
  Next i
  For Each Ky In d.Keys
    If d(Ky) < MaxCount Then d.Remove Ky
  Next Ky
  With Range("I2").Resize(d.Count)
    .Value = Application.Transpose(d.Keys)
    .TextToColumns DataType:=xlDelimited, Semicolon:=True, Other:=False
    .Offset(, 3).Value = MaxCount
  End With
End Sub

This is my sample data and results
BTW, I suggest that you investigate XL2BB for providing sample data to make it easier for helpers by not having to manually type out sample data to test with.

Dimi.xlsm
BCDEFGHIJKL
1
231518252825282
32516354516352
452528363816452
581635374535452
6410192043
7
Sheet1
 
Upvote 1
Ok, here is my 365 solution. Hope it is of some value?
Helper rows may be hidden.

PairaandTriples.xlsx
ABCDEFGHIJKLMNOPQRSTUVWXYZ
1Range of NumbersPairsTimesTripletsTimesRange Check
231518252825-28216-35-4521016182528
32516354516-352As a result of adding above range:
452528363816-452PairsTimesTripletsTimes
581635374535-45218-25218-25-282
641019204318-28216-35-452
725-283
816-352
916-452
1035-452
11
12
13
14
15
16
17
18
19
20Pairs Helper3-153-1815-183-2515-2518-253-2815-2818-2825-28
21Numbers Pairs2-52-165-162-355-3516-352-455-4516-4535-45
225-255-2825-285-3625-3628-365-3825-3828-3836-38
238-168-3516-358-3716-3735-378-4516-4535-4537-45
244-104-1910-194-2010-2019-204-4310-4319-4320-43
25Check Pairs10-1610-1816-1810-2516-2518-2510-2816-2818-2825-28
26
27
28Triplets Helper3-15-183-15-253-18-2515-18-253-15-283-18-2815-18-283-25-2815-25-2818-25-28
29Numbers Triplets2-5-162-5-352-16-355-16-352-5-452-16-455-16-452-35-455-35-4516-35-45
305-25-285-25-365-28-3625-28-365-25-385-28-3825-28-385-36-3825-36-3828-36-38
318-16-358-16-378-35-3716-35-378-16-458-35-4516-35-458-37-4516-37-4535-37-45
324-10-194-10-204-19-2010-19-204-10-434-19-4310-19-434-20-4310-20-4319-20-43
33Check Triples10-16-1810-16-2510-18-2516-18-2510-16-2810-18-2816-18-2810-25-2816-25-2818-25-28
34
Pairs & Triplets
Cell Formulas
RangeFormula
H2:H5H2=IFERROR(UNIQUE(TOCOL(IF(COUNTIF(B20:K24,B20:K24)>1,B20:K24,1/0),3)),"None")
I2:I5I2=COUNTIF(B20:K24,H2#)
L2L2=IFERROR(UNIQUE(TOCOL(IF(COUNTIF(B28:K32,B28:K32)>1,B28:K32,1/0),3)),"None")
M2M2=COUNTIF(B28:K32,L2#)
U5:U10U5=IFERROR(UNIQUE(TOCOL(IF(COUNTIF(B20:K25,B20:K25)>1,B20:K25,1/0),3)),"None")
V5:V10V5=COUNTIF(B20:K25,U5#)
X5:X6X5=IFERROR(UNIQUE(TOCOL(IF(COUNTIF(B28:K33,B28:K33)>1,B28:K33,1/0),3)),"None")
Y5:Y6Y5=COUNTIF(B28:K33,X5#)
B20:K24B20=TRANSPOSE(LET(rw,TOCOL(B2:F2&"-"&TRANSPOSE(B2:F2)),FILTER(rw,1*TEXTBEFORE(rw,"-")<1*TEXTAFTER(rw,"-"))))
B25:K25B25=TRANSPOSE(LET(rw,TOCOL(U2:Y2&"-"&TRANSPOSE(U2:Y2)),FILTER(rw,1*TEXTBEFORE(rw,"-")<1*TEXTAFTER(rw,"-"))))
B28:K32B28=TRANSPOSE(LET(tr,TOCOL(B20#&"-"&TRANSPOSE(B2:F2)),FILTER(tr,1*TEXTAFTER(TEXTBEFORE(tr,"-",2),"-")<1*TEXTAFTER(tr,"-",2))))
B33:K33B33=TRANSPOSE(LET(tr,TOCOL(B25#&"-"&TRANSPOSE(U2:Y2)),FILTER(tr,1*TEXTAFTER(TEXTBEFORE(tr,"-",2),"-")<1*TEXTAFTER(tr,"-",2))))
Dynamic array formulas.
 
Upvote 1

Forum statistics

Threads
1,215,077
Messages
6,122,995
Members
449,094
Latest member
masterms

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