Find corresponding values using multiple ranges

Rkemm5300

New Member
Joined
May 29, 2021
Messages
5
Office Version
  1. 365
Platform
  1. Windows
I have a long list with at least a dozen "PLN"s and hundreds if not thousands of combinations of RETAIL and BARGAIN prices. I'm trying to funnel them down into specific Labels. I have tried INDEX/MATCH and VLOOKUPs. I fear I may have to just write a massive IF statement unless I can find something that works consistently.

Essentially, I would like to first ID the PLN, then bump up against the RETAILS range, then against the BARGAIN range to find the final LABEL. On the left is a mini lookup table and what the labels should be. Then on the right is an example of the variations and what it *should* find for the LABEL column. I just don't know how to get to the Label column with a formula. Any help would be appreciated.


1622295970216.png
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
What would be the lookup array? Max value , min value or average of them?
 
Upvote 0
What would be the lookup array? Max value , min value or average of them?
There are 3 diff arrays in the Lookup Table. PLNs in yellow (those would be exact matches). Retails are in green (Min/Max). Bargain Prcs are in orange (Min/Max). The final Label that it should find and report onto the "Final Label" table are in blue.
 
Upvote 0
Can you post some sample data.

MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.
 
Upvote 0
LOOKUP-AGAINST TABLELIST WITH FINAL LABEL?
PLNMIN RETAILMAX RETAILMIN BARGAINMAX BARGAINLABELPLNRetail PrcBargain PrcLABEL?
AAG$ -$ -$ 2.99$ 3.99GAM 3.99AAG$ 3.99$ 0.99#N/A
AAG$ -$ -$ 4.99$ 5.99GAM 4.99AAG$ 12.95$ 3.99GAM 3.99
AAG$ 7.99$ 15.00$ 1.99$ 4.99GAM 3.99AAG$ -$ 3.99GAM 3.99
AAG$ 15.01$ 27.99$ 2.99$ 5.99GAM 4.99AAG$ -$ 5.99GAM 4.99
BIO$ -$ -$ 4.99$ 5.99BIO 4.99AAG$ 4.99$ 1.99#N/A
BIO$ -$ -$ 6.99$ 7.99BIO 6.99AAG$ 19.99$ 4.99GAM 4.99
BIO$ 14.99$ 22.99$ 1.99$ 5.99BIO 4.99AAG$ 10.00$ 1.99GAM 3.99
BIO$ 23.00$ 31.00$ 2.99$ 7.99BIO 6.99AAG$ 16.00$ 7.99#N/A
AAG$ 15.99$ 3.99GAM 4.99
BIO$ 19.95$ 1.99BIO 4.99
BIO$ 13.95$ 2.99#N/A
BIO$ 14.99$ 3.99BIO 4.99
BIO$ 22.00$ 5.99BIO 4.99
BIO$ 27.99$ 3.99BIO 6.99
BIO$ 24.99$ 5.99BIO 6.99
BIO$ 29.99$ 7.99BIO 6.99
 
Upvote 0
Thanks for that, I can understand why L3 is N/A, but why are there 3 other N/A when there are matches for them?
 
Upvote 0
If the Retail is Zero, looks only at Bargain Price to find the Label. If it *does* have a Retail price, it should look at both the Retail Min/Max and the Bargain Min/Max to find the Label. Explanations below next to the N/As...

PLNRetail PrcBargain PrcLABEL?
AAG$ 3.99$ 0.99#N/ARetail too low. Bargain too low
AAG$ 12.95$ 3.99GAM 3.99
AAG$ -$ 3.99GAM 3.99
AAG$ -$ 5.99GAM 4.99
AAG$ 4.99$ 1.99#N/ARetail too low to consider. If Retail isnt Zero, it should at least be $7.99
AAG$ 19.99$ 4.99GAM 4.99
AAG$ 10.00$ 1.99GAM 3.99
AAG$ 16.00$ 7.99#N/AWithin the correct Retail range for GAM $4.99, but Bargain is too high (Min/Max is 2.99/5.99)
AAG$ 15.99$ 3.99GAM 4.99
BIO$ 19.95$ 1.99BIO 4.99
BIO$ 13.95$ 2.99#N/ARetail too low to consider. If Retail isnt Zero, it should at least be $14.99
BIO$ 14.99$ 3.99BIO 4.99
BIO$ 22.00$ 5.99BIO 4.99
BIO$ 27.99$ 3.99BIO 6.99
BIO$ 24.99$ 5.99BIO 6.99
BIO$ 29.99$ 7.99BIO 6.99
 
Upvote 0
Ok, how about
+Fluff 1.xlsm
ABCDEFGHIJKL
1LOOKUP-AGAINST TABLELIST WITH FINAL LABEL?
2PLNMIN RETAILMAX RETAILMIN BARGAINMAX BARGAINLABELPLNRetail PrcBargain PrcLABEL?
3AAG2.993.99GAM 3.99AAG3.990.99N/A
4AAG4.995.99GAM 4.99AAG12.953.99GAM 3.99
5AAG7.99151.994.99GAM 3.99AAG3.99GAM 3.99
6AAG15.0127.992.995.99GAM 4.99AAG5.99GAM 4.99
7BIO4.995.99BIO 4.99AAG4.991.99N/A
8BIO6.997.99BIO 6.99AAG19.994.99GAM 4.99
9BIO14.9922.991.995.99BIO 4.99AAG101.99GAM 3.99
10BIO23312.997.99BIO 6.99AAG167.99N/A
11AAG15.993.99GAM 4.99
12BIO19.951.99BIO 4.99
13BIO13.952.99N/A
14BIO14.993.99BIO 4.99
15BIO225.99BIO 4.99
16BIO27.993.99BIO 6.99
17BIO24.995.99BIO 6.99
18BIO29.997.99BIO 6.99
19
Master
Cell Formulas
RangeFormula
L3:L18L3=FILTER($F$3:$F$10,($A$3:$A$10=I3)*($B$3:$B$10<=J3)*($C$3:$C$10>=J3)*($D$3:$D$10<=K3)*($E$3:$E$10>=K3),"N/A")
 
Upvote 0
Solution
That formula is a beautiful thing. Works wonderfully. Never really had an opportunity to dive into FILTER function (until now). Thank you very much!!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,606
Messages
6,120,492
Members
448,967
Latest member
visheshkotha

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