New filter function can you return all in a column

Fanta0575

New Member
Joined
Nov 19, 2019
Messages
21
Hi all, in cell L3 I have a drop down menu that gives me the option of (y,n,or all) my column for invoice paid (column g) is either a (y)or a (n). I have the new filter operation in use and I can filter for y or n because that is the data contained in column g. Is there a way I could use an (if) with the filter function to return all the data in column g if I select (all)
20191207_104428.jpg
from my drop down menu in l3!
 

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
Hi all, in cell L3 I have a drop down menu that gives me the option of (y,n,or all) my column for invoice paid (column g) is either a (y)or a (n). I have the new filter operation in use and I can filter for y or n because that is the data contained in column g. Is there a way I could use an (if) with the filter function to return all the data in column g if I select (all) View attachment 1512from my drop down menu in l3!
BTW
Formula in i5 is

=(SORT(FILTER(A2:F440,(B2:B440=J3)*(A2:A440>=I2)*(A2:A440<=K2)*(G2:G440=L3),"None Recorded In Period")))
 
Upvote 0
You could use:

=(SORT(FILTER(A2:F440,(B2:B440=J3)*(A2:A440>=I2)*(A2:A440<=K2)*(IF(L3="All",1,G2:G440=L3)),"None Recorded In Period")))
 
Upvote 0
You could use:

=(SORT(FILTER(A2:F440,(B2:B440=J3)*(A2:A440>=I2)*(A2:A440<=K2)*(IF(L3="All",1,G2:G440=L3)),"None Recorded In Period")))
Thank you so much for this RoryA, I have applied this to my supplier drop down menu list as well, it means I have a much more dynamic way of filtering information, this new filter function is amazing and much more user friendly than having to do array formulas
 
Upvote 0

Forum statistics

Threads
1,214,646
Messages
6,120,717
Members
448,985
Latest member
chocbudda

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