get cell address from formula result

stijnvanhoof

New Member
Joined
Dec 27, 2018
Messages
1
Hi I'm making a dashboard where I import raw data reports from an old fashioned ERP system into different sheets. The dashboard sheet then retrieves and calculates different results and combines these into 1 view on 1 sheet.To find the top performing customers YTD, the dashboard retrieves it's data in sheet 'sales per klant' using the aggregate function: =AGGREGATE(14;6;(('sales per klant'!$H$3:$H$1002)*('sales per klant'!$A$3:$A$1002=$A$6));1). the value returned is correct. However I also want to have the D cell retrieved that is the same as the result found with this formula so I can also link the customer name in the dashboard. So ideally I need a formula to determine the location of the cell that is the result of the formula, or another way to get this done.

In other words: My formula gives me a result based on the value in another sheet and returns this value. I also need the address of that value in the 'sales per klant' sheet so I can also display the customer name linked to that found cell result.

thanks a lot
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
[FONT=&]Hi I'm making a dashboard where I import raw data reports from an old fashioned ERP system into different sheets. The dashboard sheet then retrieves and calculates different results and combines these into 1 view on 1 sheet.[/FONT][FONT=&]To find the top performing customers YTD, the dashboard retrieves it's data in sheet 'sales per klant' using the aggregate function: [/FONT][FONT=&]=AGGREGATE(14;6;(('sales per klant'!$H$3:$H$1002)*('sales per klant'!$A$3:$A$1002=$A$6));1).[/FONT][FONT=&] [/FONT][FONT=&]the value returned is correct. However I also want to have the D cell retrieved that is the same as the result found with this formula so I can also link the customer name in the dashboard. So ideally I need a formula to determine the location of the cell that is the result of the formula, or another way to get this done.

In other words: My formula gives me a result based on the value in another sheet and returns this value. I also need the address of that value in the 'sales per klant' sheet so I can also display the customer name linked to that found cell result.

thanks a lot
[/FONT]

This works with dummy data.

Code:
=INDIRECT("Sheet4!"&ADDRESS(MATCH(MAX(Sheet4!B1:B4),Sheet4!B1:B4,0),1))

1. Note that "Sheet4!" is the sheet name used in the dummy data. Change to reflect your sheet name where the data is kept.
2. Note that the match function uses the MAX range twice, both for Match and the after the next comma.
3. Note the ,1)) reflects my use of column A to house the name of the sales person. Change to reflect the column number of your sales person's name.
 
Upvote 0
Assuming
-the formula above is in cell A2 (adjust to suit);
-the names are in D3:D1002.

Maybe something like this to get the name that corresponds to Max value (A2) in column H
=INDEX('sales per klant'!D3:D1002;AGGREGATE(14;6;(ROW('sales per klant'!D3:D1002)-ROW('sales per klant'!D3)+1)/(('sales per klant'!H3:H1002=A2)*('sales per klant'!A3:A1002=A6));1))

Hope this helps

M.
 
Upvote 0

Forum statistics

Threads
1,214,962
Messages
6,122,482
Members
449,088
Latest member
Melvetica

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