Formula to include variable within defined range

ukmike007

New Member
Joined
Sep 17, 2012
Messages
23
Office Version
  1. 365
Platform
  1. Windows
Hi All

I am trying to create a formula that contains some kind of dynamic range within it to vary where it looks for data (without VBA):

I have a list of employees, with which department they work in:

Employee Name Employee Department
Employee # 1 Department 1
Employee # 2 Department 2
Employee # 3 Department 3

I then want to create a formula in a subsequent column that will go and retrieve a number from the spreadsheet which contains the KPI's for that department e.g.

Department 1 KPI's
Department 2 KPI's
Department 3 KPI's

For example if I wanted to look up cell D5 of Employee 1's department it would be

='Department 1 KPI''s'!D5

What I need to be able to do is create a formula that will insert a referenced department name in place of what I now have a static reference "Department 1" from within the expression.

There will be dozens of departments, with actual department names and there is potential for employees to change department so I need it to be a truly variable expression please.

Thanks

Mike
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
11,685
Look into the INDIRECT function. If "Employee #1" is in A2, and "Department 1" is in B2, then your KPI formula would be:

Excel Formula:
=INDIRECT("'"&B2&" KPI''s!D5")
 

richh

Board Regular
Joined
Jun 24, 2007
Messages
243
Office Version
  1. 365
  2. 2016
You can use the INDIRECT function and VLOOKUP function.

=VLOOKUP(A2, INDIRECT("'" & B2 & " KPI'!A2:B5"), 2,0)

1627398809693.png
 

ukmike007

New Member
Joined
Sep 17, 2012
Messages
23
Office Version
  1. 365
Platform
  1. Windows
Thanks both... I had to tweak it by removing the ' from the tab name as it was not working, but I have a working solution between your answers.
 

smozgur

BatCoder
Joined
Feb 28, 2002
Messages
1,584
Thanks both... I had to tweak it by removing the ' from the tab name as it was not working, but I have a working solution between your answers.

Glad to hear you got the solution.

Do you mind posting about your solution? Then it is perfectly fine to mark your post as the solution to help future readers.
 

Forum statistics

Threads
1,148,250
Messages
5,745,638
Members
423,965
Latest member
visionquest1972

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