Index Max the xth element to VBA

pchatziko

New Member
Joined
Apr 30, 2021
Messages
10
Office Version
  1. 365
Platform
  1. Windows
Hello i have the following problem

In the first row i have a list of elements and at subsequent rows random numbers under each element and i want to match the element with the max of each row, all the max values though not just the first one. This is achieved by the following function =IF(COLUMNS(F2:$F2)<=$E2,INDEX($A$1:$C$1,SMALL(IF($A2:$C2=$D2,COLUMN($A2:$C2)),COLUMNS(F2:$F2))),"") and dragged to the right the desired result is shown in the yellow cells
2ndmax.PNG

The following code is giving a type mismatch error and my vba is not so deep to understand why.
VBA Code:
For i=2 to something

For j=1 to 3

Cells(count, j + 8) = WorksheetFunction.Index(Range(Cells(1, 1), Cells(1, 3)), WorksheetFunction.Small(IIf(Range(Cells(i, 1), Cells(i, 3)).Value = Cells(i, 4), Range(Cells(i, 1), Cells(i, 3)).Column, ""), Range(Cells(count, j)).Column))

Next j

Next i

Can you please fix the previous code or suggest anything that does the same thing?

Thanks a lot
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).

pchatziko

New Member
Joined
Apr 30, 2021
Messages
10
Office Version
  1. 365
Platform
  1. Windows
Small typo in the above code
cells(i,j+8)=... not cells(count,j+8)
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,618
Office Version
  1. 365
Platform
  1. Windows
Try changing the IIf to If
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,618
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

As you are using 365 how about
VBA Code:
For i = 2 To something
   A = Evaluate("Filter(A1:C1," & Range("A" & i).Resize(, 3).Address & "=" & Range("D" & i).Address & ")")
   Cells(i, 6).Resize(, UBound(A)).Value = A

Next i
 
Solution

pchatziko

New Member
Joined
Apr 30, 2021
Messages
10
Office Version
  1. 365
Platform
  1. Windows
To be fair i can't fully grasp the solution but it works like a charm. Thank you
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,618
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

It's basically just using the Xl filter function, which does the same as your formula
+Fluff 1.xlsm
ABCDEFG
1abc
245552bc
38588ac
Main
Cell Formulas
RangeFormula
F2:G3F2=FILTER($A$1:$C$1,A2:C2=D2)
Dynamic array formulas.
 

pchatziko

New Member
Joined
Apr 30, 2021
Messages
10
Office Version
  1. 365
Platform
  1. Windows
Yeap got it just wasn't aware of this. Thanks very much
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
65,618
Office Version
  1. 365
Platform
  1. Windows
You're welcome & thanks for the feedback.
 

Forum statistics

Threads
1,147,571
Messages
5,741,895
Members
423,693
Latest member
Excelquestion35

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
Top