Unique Formula for visible cells only

Chewyhairball

Board Regular
Joined
Nov 30, 2017
Messages
172
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Hi

I am using the unique formula to extract a list of unique values from a table and I have to say I am a big fan of this formula having just discovered it.

=UNIQUE(Table5[[#Data],[Building]])

Is there a way to use this formula ( or similar) to extract a unique list from visible rows only?

When I have other filters applied it would be good to be able to extract only the visible rows to create the unique list. I use this column to create a drop down list so I guess what my goal is is to
create a dynamic dropdown list.

I am not looking for VBA for this rather trying to find out if there is a way to do it with a formula.

thanks

Rory

Rory
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
13,528
Office Version
  1. 365
Platform
  1. Windows
I would say use a helper column with a subtotal formula for the row, for example
Excel Formula:
=SUBTOTAL(2,[@Data])
Then change the unique formula to
Excel Formula:
=UNIQUE(FILTER(Table5[[#Data],[Building]],Table5[Helper]=1,""))
Think that is right, but without setting up a table to test the syntax, there could be any number of errors :oops:
 
Solution

Chewyhairball

Board Regular
Joined
Nov 30, 2017
Messages
172
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Thanks jason. Ill give it a bash and let you know how i get on :)
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
62,252
Office Version
  1. 365
Platform
  1. Windows
Whilst I'd go with the helper column that Jason has suggested, another option would be
Excel Formula:
=UNIQUE(FILTER(Table5[Building],SUBTOTAL(3,OFFSET(Table5[[#Headers],[Building]],ROW(Table5[Building])-ROW(Table5[[#Headers],[Building]]),0))))
although this is volatile, which could have an adverse affect on the performance of your workbook.
 

Chewyhairball

Board Regular
Joined
Nov 30, 2017
Messages
172
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Hi, I went with the helper table and it is perfect for what i need. Thank you both for the replies :)
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
62,252
Office Version
  1. 365
Platform
  1. Windows
Glad we could help & thanks for the feedback.
 

Forum statistics

Threads
1,141,060
Messages
5,704,041
Members
421,324
Latest member
Devo182

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