Filter based on Sub Criteria?

mrmmickle1

Well-known Member
Joined
May 11, 2012
Messages
2,461
I would like to filter based on sub criteria.

I have 4 different possible field values in column A. I would like the filter to show only the highest (MAX) % for each of the four possibilities. Can someone please assist me in accomplishing this if it is possible?

The problem I can foresee is what if by getting rid of a low percent for one field value it gets rid of the highest % for another value.

For Example. If the CCC high was 95% but there was also a value for CCC that had 60% and AAA high is 60%..... then by eliminating the 60% for CCC it is no longer possible to display it for AAA.....


Start Data:


Excel 2012
AB
1Filter Field% Field
2AAA5%
3AAA55%
4BBB90%
5BBB95%
6CCC20%
7CCC25%
8CCC60%
9DDD50%
10DDD60%
11DDD23%
Sheet1


After Filter:


Excel 2012
AB
1Filter Field% Field
3AAA55%
5BBB95%
8CCC60%
10DDD60%
Sheet1


If there is a solution other then by filtering it would be much appreciated.
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
The only thing that comes to my mind is to add a helper column in column C with below formula (must be entered with CTRL + SHIFT + ENTER, not only ENTER):

Code:
=IF(B2=MAX(IF($A$2:$A$11=A2,$B$2:$B$11,0)),TRUE,FALSE)

And then just filter TRUEs in column C and you will get MAX values for each unique value in column A.

See sample workbook for reference:

Code:
https://app.box.com/s/1cix51c1h2nhz7yk0p6y0x02js3x7vms
 
Upvote 0
This appears like it will work. For my purposes I am trying to enter the formula via VBA. When I run this line of code:

Code:
  Sheets(2).Range("J2:J" & ReportLRow).FormulaArray = "=IF(H2=MAX(IF($A$2:$A$" & ReportLRow & "=A2,$H$2:$H$" & ReportLRow & ",0)),TRUE,FALSE)"

It enters the same formula over and over again like this:

Excel 2012
J
1MAX Value?
2FALSE
3FALSE
4FALSE
5FALSE

<tbody>
</tbody>
Report

Array Formulas
CellFormula
J2:J1081{=IF(H2=MAX(IF($A$2:$A$1081=A2,$H$2:$H$1081,0)),TRUE,FALSE)}

<tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>




How can I fix this issue??? I need it to go H2, H3, H4 etc.... A2, A3, A4

Thank you so much for the assistance.

Besides putting it in a loop like this:

Code:
For x = 2 To ReportLrow

Sheets(2).Range("J"& x).FormulaArray = "=IF(H" & x & "=MAX(IF($A$2:$A$" & ReportLRow & "=A" & x & ",$H$2:$H$" & ReportLRow & ",0)),TRUE,FALSE)"

Next x
 
Last edited:
Upvote 0
To be honest for me there are two solutions - either you go with formulas and you just apply it for your range manually or you go with VBA and the calculations are done within the code and only values not formulas are returned to the sheet. I not a fan of applying formulas using VBA and I don't know how to help you with that. If I would have to apply formulas via VBA I would go with the loop.
 
Upvote 0
RatExcel,

Thanks so much for the help. The loop works. I will use it for the time being! I appreciate you helping me solve my issue. :)
 
Upvote 0

Forum statistics

Threads
1,216,112
Messages
6,128,901
Members
449,477
Latest member
panjongshing

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