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!
 

Some videos you may like

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number

Yongle

Well-known Member
Joined
Mar 11, 2015
Messages
6,747
Office Version
  1. 365
Platform
  1. Windows
=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)))
 

Norie

Well-known Member
Joined
Apr 28, 2004
Messages
75,831
Office Version
  1. 365
Platform
  1. Windows
Are any of the values involved dates formatted to show only the year?
 

Yongle

Well-known Member
Joined
Mar 11, 2015
Messages
6,747
Office Version
  1. 365
Platform
  1. Windows
@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
 

Yongle

Well-known Member
Joined
Mar 11, 2015
Messages
6,747
Office Version
  1. 365
Platform
  1. Windows
thanks for your feedback
(y)
 

Watch MrExcel Video

Forum statistics

Threads
1,109,032
Messages
5,526,358
Members
409,697
Latest member
christopherlewis1620

This Week's Hot Topics

Top