Shorter Formula Possible?

dcofer

Board Regular
Joined
Jun 25, 2004
Messages
203
Hello All,

I am using the formula below to lookup a price based upon two variables, the type of wood, and the size of the pieces.

The type of wood that is being looked up is in cell G21 and there are seven possible types (Ali Posts, Ironbark, Kwila, etc.) and the size to be looked up is in G22. Based upon the type of wood, there are different sizes available. As you can see from the ranges, one wood type only has 4 sizes, one has 9 sizes and the others have 10 sizes. To complicate matters even more, the ranges of data that contains the wood type, sizes, and prices are in separate areas. The prices are not contained in one large table or range. For example, the prices for Ironbark are in D28 to E37 on a seperate sheet and the prices for Redwood are in L28 to M36.

The formula below works perfectly, but it is very long and convoluted. Is there a simplier way to look up the prices? Perhaps with a shorter formula?

I tried to make the ranges of prices a table, but since there are blank rows (because all types of wood do not have 10 sizes), the data would not go into a table, and a Pivot Table was not possible for the same reason.

If anyone knows a better way to accomplish the lookup, I would appreciate it. Again, this formula works, but I am looking for a simplier formula, if one exists.


=IF(G21="Ali Posts",VLOOKUP(G22,Sheet2!B28:C31,2,0),IF(G21="Ironbark",VLOOKUP(G22,Sheet2!D28:E37,2,0),IF(G21="Kwila",VLOOKUP(G22,Sheet2!F28:G37,2,0),IF(G21="Merbau",VLOOKUP(G22,Sheet2!H28:I37,2,0),IF(G21="Radiata Pine",VLOOKUP(G22,Sheet2!J28:K37,2,0),IF(G21="Redwood",VLOOKUP(G22,Sheet2!L28:M36,2,0),IF(G21="Steel",VLOOKUP(G22,Sheet2!N28:O37,2,0))))))))


Thanks,

David
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
This is untested, but try:

=VLOOKUP(G22,OFFSET(A28:B31,0,MATCH(G21,{"Ali Posts","Ironbark","Kwila","Merbau","Radiata Pine","Redwood","Steel"},0)),2,0)
 
Upvote 0
MrKowz,

When I tried your formula, Excel first said a parenthesis was missing. When I added that, it then said the formula had too few arguments.

I am not for sure how to post a sample of the data layout.

The type of wood is in Cell G21 and the size is in G22, both on Sheet 1. The prices are on Sheet 2 in seperate areas by types of wood. That is what makes the lookup so difficult.

The long nested IF formula works, but I was hoping for somthing simplier.

Thanks,

David
 
Upvote 0
Tested this one - works on my end:

=VLOOKUP(G22,OFFSET(Sheet2!A28:B31,0,MATCH(G21,{"Ali Posts","Ironbark","Kwila","Merbau","Radiata Pine","Redwood","Steel"},0)*2),2,0)
 
Upvote 0
MrKowz,

I get a #N/A error message with that formula.

The problem may be the ranges on Sheet 2. The 7 types of wood are listed horizontally from B27 to O27 (B27, D27, F27, H27, J27, L27, and N27). The sizes of wood are listed in Columns B, D, F, H, J, L, and N, beginning in row 28 going down as many rows as there are sizes for that type of wood. The prices are listed in Columns C, E, G, I, K, M, and N beginning in row 28 and going down as many rows as there are types of lumber.

That is what makes the lookup so difficult.

Thanks,

David
 
Upvote 0
I see - in this case, I believe you just need an INDEX/MATCH.

Do you have difference sizes of wood for each type?
 
Upvote 0
Yes, unfortunately, there are different sizes for the different woods. One (Ali Posts) only has 4 sizes, one (Redwood) has 9 sizes, and the other 5 have ten sizes. That is making the lookup a big problem. The different number of sizes kept me from formatting it as a table or using a pivot table.

How would I write an Index/Match formula?

Thanks,

David
 
Upvote 0
I see - let me play around with some formulas a bit and see if I can't come up with a solution that dynamically adjusts the lookup size. I have worked through one solution that should at least get you by for now:

=VLOOKUP(G22,OFFSET(Sheet2!B29:C50,0,(MATCH(G21,{"Ali Posts","Ironbark","Kwila","Merbau","Radiata Pine","Redwood","Steel"},0)-1)*2),2,0)

But one other question - will you have any data below the table you are looking in? Also, are the sizes stored as a number or as text (if you have anything other than a number in the cell, it will be text).
 
Upvote 0
How about something like...


Code:
=VLOOKUP(G22,OFFSET(Sheet2!B27,0,(MATCH(G21,Sheet2!B27:O27,0)-1),15,2),2,0)

Regards

Roger
 
Upvote 0

Forum statistics

Threads
1,224,587
Messages
6,179,740
Members
452,940
Latest member
rootytrip

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