Pricing based on multiple factors

jeffamore

New Member
Joined
Nov 25, 2020
Messages
5
Office Version
  1. 2010
Platform
  1. Windows
Hi all... having some trouble getting this to work the way I'd like. Please refer to the worksheet image... it's the best way for me to explain what I'm trying to do.

I want to look at the first three characters in the Indicator column (column A), look at the appropriate table that matches that value in columns F and G, grab the correct dollar amount in that table from column G based on the number of units in column B that corresponds to the number in column F, and then multiply B and F in column C. I've included the expected results for rows 2-9 in columns J and K. This would be done over thousands of rows and will be repeated several times with different variations, so I only want to do this once and just be able to copy the formula all the way down column C. Any help is greatly appreciated!
 

Attachments

  • Excel Example.JPG
    Excel Example.JPG
    216.6 KB · Views: 11

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
Welcome to the board!

I'd start solving this by creating named ranges for each of those lookup tables: Select the cells F3:G7 and in the address bar write something like Range101. Once you've named all your lookup ranges using the same pattern you can use the following formula:
=VLOOKUP(B2,INDIRECT("Range"&LEFT(A2,3)),2)*B2

The INDIRECT function turns text to a range reference. Thus "Range"&LEFT(A2,3) refers to the named range "Range101". The rest of the formula is just a basic VLOOKUP.

You can name your ranges pretty much whatever you want to as long as it's a single word and it doesn't start with a number. The named range can't overlap an existing cell address so something like "Rng101" doesn't work.

There's at least a couple more ways I could solve this but this method is by far the easiest to read and maintain.
 
Upvote 0
Solution
Welcome to the board!

I'd start solving this by creating named ranges for each of those lookup tables: Select the cells F3:G7 and in the address bar write something like Range101. Once you've named all your lookup ranges using the same pattern you can use the following formula:
=VLOOKUP(B2,INDIRECT("Range"&LEFT(A2,3)),2)*B2

The INDIRECT function turns text to a range reference. Thus "Range"&LEFT(A2,3) refers to the named range "Range101". The rest of the formula is just a basic VLOOKUP.

You can name your ranges pretty much whatever you want to as long as it's a single word and it doesn't start with a number. The named range can't overlap an existing cell address so something like "Rng101" doesn't work.

There's at least a couple more ways I could solve this but this method is by far the easiest to read and maintain.
This works perfectly and should be so easy to maintain and modify as needed. Thank you so much!
 
Upvote 0

Forum statistics

Threads
1,213,557
Messages
6,114,287
Members
448,562
Latest member
Flashbond

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