Creating a dynamic filter

jdhfch

Board Regular
Joined
Jan 25, 2018
Messages
69
Office Version
  1. 365
Platform
  1. Windows
Hi,

I am trying to create a workbook that dynamically filters positive values and moves the categories and values up the sheet to ensure that there are no gaps where there is no data present. The report will be looking up to external data so I can't just use a standard filter. An example of what I would like to achieve is attached, giving 3 examples (there would only be one set of data per report, the 3 are just to show different examples) you can see the raw data in columns A & B and what I would like to output in D & E. If it can be done just in formulas, that would be great, but if it needs to be a VBA project, that is ok too. FYI - this will be used for multiple customers from the same workbook

Is this possible, please?
 

Attachments

  • Capture.JPG
    Capture.JPG
    46.4 KB · Views: 9

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college
Whats your current excel version? For Excel 365 and 2021 you can use the below formula. For 3rd example:-

=FILTER(A18:B23,B18:B23>0)
 
Upvote 0
I am using excel 2016 - this function doesn't work
 
Upvote 0
How about in D3 dragged down & across
Excel Formula:
=IFERROR(INDEX(A$3:A$8,AGGREGATE(15,6,(ROW($B$3:$B$8)-ROW($B$3)+1)/($B$3:$B$8>0),ROWS(D$3:D3))),"")
 
Upvote 0
Solution
How about in D3 dragged down & across
Excel Formula:
=IFERROR(INDEX(A$3:A$8,AGGREGATE(15,6,(ROW($B$3:$B$8)-ROW($B$3)+1)/($B$3:$B$8>0),ROWS(D$3:D3))),"")
Excellent - Thank you!
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,213,558
Messages
6,114,296
Members
448,564
Latest member
ED38

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