Table Header Won't Match

tm4170

New Member
Joined
Mar 14, 2019
Messages
2
Hi,

I'm having a problem with an INDEX/MATCH lookup with the reference field off of a table header - for background, I want to sum a column of the table using =SUM(INDEX(Table2[[2001]:[2018]],,MATCH(F518,Table2[[#Headers],[2001]:[2018]],0))) - however the table header does not match the reference cell despite having the same contents. The header cell and the reference cell are both numbers (specifically, years), which I've noticed causes a problem as if I change the header/reference to non-numeric data it will match.

Does anyone know a way to match a table header that has numeric data?

I'm using excel 2016 on a windows 10 machine.

Thanks in advance for any help and let me know if there is any other info on my end that is needed!
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
=SUM(INDEX(Table2[[2001]:[2018]],,MATCH(F518,Table2[[#Headers],[2001]:[2018]],0)))

replace with
=SUM(INDEX(Table2[[2001]:[2018]],,MATCH(TEXT(F518,"0"),Table2[[#Headers],[2001]:[2018]],0)))
 
Upvote 0
Are any of the values involved dates formatted to show only the year?
 
Upvote 0
@Norie - that is a valid point :)

In which case
TEXT(F518,"0")
TEXT(YEAR(F518),"0")

But also ...
I have not noticed this behaviour before with matching values in table headers (I use Offset to return the column with month and years) , so I played around with the values and found that Excel does indeed not match numbers in the headers

On further testing, it turns out that my formula in post#2 only worked because the year headers in my table were preceded by an apostrophe
- without the apostrophe the match failed

So in addition to amending the formula as described, also amend table headers by preceding year with apostrophe
change 2001 to '2001 and drag across
 
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,289
Members
452,631
Latest member
a_potato

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