return value based on matrix column name and row name

wulp2

New Member
Joined
Jan 31, 2019
Messages
4
Hi,

There are a lot of INDEX/MATCH/VLOOKUP examples out there but I could not find the one that I need.

I want the following:
I have 2 tables,

table 1:
ProjectCodeTotals
C110
C25
C30
D27

<colgroup><col><col><col></colgroup><tbody>
</tbody>

and table 2 (the # and the @ are normally not there, it is for this example):
Code

<tbody style="background-attachment: scroll; background-clip: border-box; background-color: transparent; background-image: none; background-origin: padding-box; background-position-x: 0%; background-position-y: 0%; background-repeat: repeat; background-size: auto; color: rgb(34, 34, 34); font-family: Verdana,Arial,Tahoma,Calibri,Geneva,sans-serif; font-size: 13px; font-size-adjust: none; font-stretch: 100%; font-style: normal; font-variant: normal; font-weight: 400; line-height: normal; margin-bottom: 0px; margin-left: 0px; margin-right: 0px; margin-top: 0px; padding-bottom: 0px; padding-left: 0px; padding-right: 0px; padding-top: 0px;">
</tbody>
Project12
C#
A@
C

<colgroup><col><col><col></colgroup><tbody>
</tbody>

I need to have a formula in table 2 to find the value in the totals column in table 1 by using the colum names and the row names in table 2.
In this example, a 5 should be where the # is (there is a C2 in table 1) and if there is no simularity in table 1 it should not return anything like for example the @ (there is no A2 in table 1).

I hope I am clear enough for someone to help me out.

Regards,
Raoul
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
try this


Book1
ABC
1ProjectCodeTotals
2C110
3C25
4C30
5D27
6
7
8Project12
9C105
10A
11D7
Sheet1
Cell Formulas
RangeFormula
B9{=IFERROR(INDEX($C$2:$C$5,MATCH(B$8,IF($A$2:$A$5=$A9,$B$2:$B$5),0)),"")}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
Hi,

Not sure to fully understand your structure ...

With the number 2 of your table 2 located in cell C11 ...

do you need
Code:
=INDEX($C$2:$C$5,C11)

Hope this will help
 
Upvote 0
BOTH, thank you for the quick response, well received.
@AlanY, that would indeed help, I however do not want to use an array formula as table 2 changes in size. @James006, the example of AlanY shows EXACTLY what I want, he also has an answer but I do not want to use an array if remotely possible.

I could also use a helper column to merge column A & B (=A2&B2) but I would like to do without a helper column.
 
Upvote 0
you can use sumproduct instead without the arrays formula like this


Book1
ABCDEFGH
1ProjectCodeTotalsProject123
2C110C1050
3C25A008
4C30D070
5D27
6A38
Sheet1
Cell Formulas
RangeFormula
F2=SUMPRODUCT(($A$2:$A$1500=$E2)*($B$2:$B$1500=F$1),$C$2:$C$1500)
 
Upvote 0

Forum statistics

Threads
1,215,064
Messages
6,122,941
Members
449,094
Latest member
teemeren

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