The Company,Department and Sub Department has to be kept in separate worksheets as they are imported but can convert to tables.
That's a curve. I was always dealing with changing shop floor data and dealing with corporate database tables.
But, Yes, to do it right, it should all be in one table, as per this example: Company, Dept & Sub, sorted in that order and then a Helper column concatenating Company & Dept.
[pre]
Company Dept Sub Helper
10 00 000001 1000
10 00 000004 1000
10 00 000060 1000
10 01 000002 1001
10 01 000010 1001
10 01 000070 1001
10 02 000003 1002
10 02 000050 1002
10 02 000080 1002
20 05 000085 2005
20 05 000063 2005
20 05 000022 2005
20 06 000001 2006
20 06 000058 2006
20 06 000041 2006
20 07 000006 2007
20 07 000079 2007
20 07 000093 2007
[/pre]
Make the table a
Structured Table. My table name is Table1.
Here's the source for the Company Data Validation List, Department Data Validation List & Sub Dept list
[tt]=UNIQUE(Table1[Company])
=UNIQUE(OFFSET(Table1[Company],MATCH($B$3,Table1[Company],0)-1,1,COUNTIF(Table1[Company],$B$3),1))
=UNIQUE(OFFSET(Table1[Company],MATCH($B$3&$C$3,Table1[Helper],0)-1,2,COUNTIF(Table1[Helper],$B$3&$C$3),1))
[/tt]
Skip,
Just traded in my OLD subtlety...
for a NUance!![[tongue] [tongue] [tongue]](/data/assets/smilies/tongue.gif)
"The most incomprehensible thing about the universe is that it is comprehensible" A. Einstein
You Matter...
unless you multiply yourself by the speed of light squared, then...
You Energy!