Find most match row #

aqeelnokia99

Board Regular
Joined
Dec 23, 2018
Messages
145
Office Version
  1. 2013
Platform
  1. Windows
Hello i try to find most match row # in a array formula i have 2 sheet with same coloms name like i post down i make a formula like Po sheet 1 = all PO row in sheet 2 and qty sheet 1=all Qty in sheet 2 and its give me true and fales in array so i want to get the row # of whre most true like row 5
<style type="text/css"> table.tableizer-table { font-size: 12px; border: 1px solid #CCC ; font-family: Arial, Helvetica, sans-serif; } .tableizer-table td { padding: 4px; margin: 3px; border: 1px solid #CCC ; } .tableizer-table th { background-color: #104E8B ; color: #FFF ; font-weight: bold; }</style>
[TABLE="class: tableizer-table"]
<thead>[TR="class: tableizer-firstrow"]
[TH]PO[/TH]
[TH]qty[/TH]
[TH]size[/TH]
[TH]design[/TH]
[TH]color[/TH]
[TH]row[/TH]
[/TR]
</thead><tbody> [TR]
[TD]TRUE[/TD]
[TD]FALSE[/TD]
[TD]TRUE[/TD]
[TD]FALSE[/TD]
[TD]FALSE[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]FALSE[/TD]
[TD]FALSE[/TD]
[TD]FALSE[/TD]
[TD]FALSE[/TD]
[TD]FALSE[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]FALSE[/TD]
[TD]FALSE[/TD]
[TD]FALSE[/TD]
[TD]FALSE[/TD]
[TD]FALSE[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD]TRUE[/TD]
[TD]TRUE[/TD]
[TD]FALSE[/TD]
[TD]TRUE[/TD]
[TD]FALSE[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]TRUE[/TD]
[TD]TRUE[/TD]
[TD]TRUE[/TD]
[TD]TRUE[/TD]
[TD]FALES[/TD]
[TD]5[/TD]
[/TR]
</tbody>[/TABLE]
 
Speaking of VBA, it might be worth using a UDF (User-Defined Function). If you want to try that, open a copy of your workbook. Press Alt-F11 to open the VBA editor. Press Alt-IM to insert a module. Paste the following code in the window that opens:

Code:
Public Function MatchMost(ByVal range1 As Range, ByVal range2 As Range, ByVal range3 As Range)
Dim i As Long, j As Long, MyData As Variant, hdrs1 As Variant, vals As Variant, c(1 To 100) As Variant
Dim m As Long, m2 As Long, n As Long


    MyData = range1.Value
    hdrs1 = range2.Value
    vals = range3.Value
    
    For i = 1 To UBound(hdrs1, 2)
        c(i) = WorksheetFunction.Match(hdrs1(1, i), WorksheetFunction.Index(MyData, 1, 0), 0)
    Next i
    
    m = -1
    m2 = 0
    
    For i = 2 To UBound(MyData)
        n = 0
        For j = 1 To UBound(hdrs1, 2)
            If MyData(i, c(j)) = vals(1, j) Then n = n + 1
        Next j
        If n > m Then
            m2 = i
            m = n
        End If
    Next i
    
    MatchMost = MyData(m2, 1) & ": "
    For i = 1 To UBound(hdrs1, 2)
        If MyData(m2, c(i)) <> vals(1, i) Then MatchMost = MatchMost & hdrs1(1, i) & " "
    Next i
        
End Function
Press Alt-Q to close the editor. Now enter this formula on your sheet:


Book1
ABCDEFGHIJKLMNOPQRS
1rowPOvirantsizecolorcfdesignqtyformulaPOcfsizevirantcolordesignqty
21a3t12x30red1multi93: cf virant colora12x30greenmimi9
32b312x40yellow2uni37
43a5d12x303mimi9
54c212x45blue1multi62
65a12d12x50green2mimi27
76bg412x32dark3mimi25
Sheet4
Cell Formulas
RangeFormula
L2=matchmost($A$1:$J$7,$M$1:$S$1,M2:S2)


The formula is much simpler, if you don't mind the VBA.
 
Upvote 0

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
i using =TRIM(IF(I2<>INDEX(B2:B7,$H$2),I$1&" ","")&IF(J2<>INDEX(C2:C7,$H$2),J$1&" ","")&IF(K2<>INDEX(D2:D7,$H$2),K$1&" ","")&IF(L2<>INDEX(E2:E7,$H$2),L$1&" ","")&IF(M2<>INDEX(F2:F7,$H$2),M$1&" ",""))
and
{=INDEX($A$2:$A$7,MATCH(MAX((M2=$B$2:$B$7)+(N2=$F$2:$F$7)+(O2=$D$2:$D$7)+(P2=$C$2:$C$7)+(Q2=$E$2:$E$7)+(R2=$G$2:$G$7)+(S2=$J$2:$J$7)),(M2=$B$2:$B$7)+(N2=$F$2:$F$7)+(O2=$D$2:$D$7)+(P2=$C$2:$C$7)+(Q2=$E$2:$E$7)+(R2=$G$2:$G$7)+(S2=$J$2:$J$7),0))}
its work very well
 
Upvote 0

Forum statistics

Threads
1,223,214
Messages
6,170,771
Members
452,353
Latest member
strainu

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