Hi bruce21,
It sounds like you may want to use AGGREGATE. Take a look and tell me if this is what you are looking for.
This is my data sheet with sales by name:
| A | B | C | D | E |
---|
Name | Company | | | | |
Alf Carruthers | ACME Widgets | | | | |
Bert Jones | Altwood Bits | | | | |
Alf Carruthers | Carter PLC | | | | |
Alf Carruthers | Green & Son | | | | |
Bert Jones | Mint Trading | | | | |
Alf Carruthers | Bridges Stuff | | | | |
Bert Jones | Jones & Jones | | | | |
Kathy Bridges | Jones & Jones | | | | |
Kathy Bridges | Zoe & Partners | | | | |
Kathy Bridges | Lily Interiors | | | | |
Kathy Bridges | Easy Partners | | | | |
Sarah Pollard | ACME Widgets | | | | |
Kathy Bridges | Jones & Jones | | | | |
<tbody>
[TD="align: center"]3[/TD]
[TD="align: center"]Sales 2017[/TD]
[TD="align: center"]Sales 2018[/TD]
[TD="align: center"]Sales 2019[/TD]
[TD="align: center"]4[/TD]
[TD="align: center"]$21,315[/TD]
[TD="align: center"]$30,346[/TD]
[TD="align: center"]$21,994[/TD]
[TD="align: center"]5[/TD]
[TD="align: center"]$38,201[/TD]
[TD="align: center"]$25,608[/TD]
[TD="align: center"]$59,469[/TD]
[TD="align: center"]6[/TD]
[TD="align: center"]$41,455[/TD]
[TD="align: center"]$70,711[/TD]
[TD="align: center"]$40,436[/TD]
[TD="align: center"]7[/TD]
[TD="align: center"]$46,016[/TD]
[TD="align: center"]$15,851[/TD]
[TD="align: center"]$66,310[/TD]
[TD="align: center"]8[/TD]
[TD="align: center"]$40,345[/TD]
[TD="align: center"]$24,567[/TD]
[TD="align: center"]$82,349[/TD]
[TD="align: center"]9[/TD]
[TD="align: center"]$70,662[/TD]
[TD="align: center"]$64,842[/TD]
[TD="align: center"]$46,153[/TD]
[TD="align: center"]10[/TD]
[TD="align: center"]$31,668[/TD]
[TD="align: center"]$82,986[/TD]
[TD="align: center"]$33,251[/TD]
[TD="align: center"]11[/TD]
[TD="align: center"]$33,857[/TD]
[TD="align: center"]$69,499[/TD]
[TD="align: center"]$84,756[/TD]
[TD="align: center"]12[/TD]
[TD="align: center"]$15,573[/TD]
[TD="align: center"]$46,401[/TD]
[TD="align: center"]$68,767[/TD]
[TD="align: center"]13[/TD]
[TD="align: center"]$65,996[/TD]
[TD="align: center"]$82,312[/TD]
[TD="align: center"]$41,678[/TD]
[TD="align: center"]14[/TD]
[TD="align: center"]$72,262[/TD]
[TD="align: center"]$48,258[/TD]
[TD="align: center"]$49,174[/TD]
[TD="align: center"]15[/TD]
[TD="align: center"]$19,159[/TD]
[TD="align: center"]$68,318[/TD]
[TD="align: center"]$65,540[/TD]
[TD="align: center"]16[/TD]
[TD="align: center"]$62,291[/TD]
[TD="align: center"]$52,788[/TD]
[TD="align: center"]$38,300[/TD]
</tbody>
SalesData
From your dropdown in B3 on your main sheet you select the name. The formulae in D3 to G3 (copied down as many hits as you may have) will show just the rows matching the selected name.
<tbody>
[TD="align: center"]2[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: center"]Sales 2017[/TD]
[TD="align: center"]Sales 2018[/TD]
[TD="align: center"]Sales 2019[/TD]
[TD="align: center"]3[/TD]
[TD="align: right"]Name=[/TD]
[TD="align: center"]Kathy Bridges[/TD]
[TD="align: right"][/TD]
[TD="align: center"]Jones & Jones[/TD]
[TD="align: center"]$33,857[/TD]
[TD="align: center"]$69,499[/TD]
[TD="align: center"]$84,756[/TD]
[TD="align: center"]4[/TD]
[TD="align: right"]Count=[/TD]
[TD="align: center"]5[/TD]
[TD="align: right"][/TD]
[TD="align: center"]Zoe & Partners[/TD]
[TD="align: center"]$15,573[/TD]
[TD="align: center"]$46,401[/TD]
[TD="align: center"]$68,767[/TD]
[TD="align: center"]5[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: center"]Lily Interiors[/TD]
[TD="align: center"]$65,996[/TD]
[TD="align: center"]$82,312[/TD]
[TD="align: center"]$41,678[/TD]
[TD="align: center"]6[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: center"]Easy Partners[/TD]
[TD="align: center"]$72,262[/TD]
[TD="align: center"]$48,258[/TD]
[TD="align: center"]$49,174[/TD]
[TD="align: center"]7[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: center"]Jones & Jones[/TD]
[TD="align: center"]$62,291[/TD]
[TD="align: center"]$52,788[/TD]
[TD="align: center"]$38,300[/TD]
[TD="align: center"]8[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
</tbody>
bruce21
[TABLE="width: 85%"]
<tbody>[TR]
[TD]
Worksheet Formulas[TABLE="width: 100%"]
<tbody>[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]
[TH]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
[TR]
[TH="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]D3[/TH]
[TD="align: left"]=IF(
ROWS($D$3:$D3)>$B$4,"",INDEX(SalesData!B$4:B$999,AGGREGATE(15,6,ROW(SalesData!$A$4:$A$999)-ROW($A$3)/(SalesData!$A$4:$A$999=$B$3),ROWS(D$3:D3))))[/TD]
[/TR]
[TR]
[TH="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]E3[/TH]
[TD="align: left"]=IF(
ROWS($D$3:$D3)>$B$4,"",INDEX(SalesData!C$4:C$999,AGGREGATE(15,6,ROW(SalesData!$A$4:$A$999)-ROW($A$3)/(SalesData!$A$4:$A$999=$B$3),ROWS(E$3:E3))))[/TD]
[/TR]
[TR]
[TH="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]F3[/TH]
[TD="align: left"]=IF(
ROWS($D$3:$D3)>$B$4,"",INDEX(SalesData!D$4:D$999,AGGREGATE(15,6,ROW(SalesData!$A$4:$A$999)-ROW($A$3)/(SalesData!$A$4:$A$999=$B$3),ROWS(F$3:F3))))[/TD]
[/TR]
[TR]
[TH="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]G3[/TH]
[TD="align: left"]=IF(
ROWS($D$3:$D3)>$B$4,"",INDEX(SalesData!E$4:E$999,AGGREGATE(15,6,ROW(SalesData!$A$4:$A$999)-ROW($A$3)/(SalesData!$A$4:$A$999=$B$3),ROWS(G$3:G3))))[/TD]
[/TR]
[TR]
[TH="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]B4[/TH]
[TD="align: left"]=COUNTIF(
SalesData!A:A,B3)[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]
Only the INDEX column changes (B,C,D,E as they're all next to each other) between D and G.