Referring to a Table column by it's column number

mark hansen

Well-known Member
Joined
Mar 6, 2006
Messages
534
Office Version
  1. 2016
Platform
  1. Windows
I have a list of column headers and I need to count the amount of times "No" shows up in a column for a given date range and person name. I have this formula, which works well.
=COUNTIFS(Table1[Date of Visit],">="&$AY$32,Table1[Date of Visit],"<="&$AY$33,Table1[Nurse name],$BA$31,Table1[Pediatric Question 1],"No")

The "Pediatric Question 1" is the header name as well as the label name to indicate which column the count is for. How would I change " Table1[Pediatric Question 1],"No" " so the column header name is picked up from the same name used as a label name. In my searches for this, I have found, " =MATCH($AY35,Table1[#Headers],0) " which returns the number 7, which is the column number for Pediatric Question 1. (AY35 is where the column label name is.)

How can I incorporate the match statement to indicate the column to count the word "No" in the column with the header in AY35?

I can go down the list of column header labels changing the formula to the new column headers, but there should be a better way.

Thanks for any ideas.
Mark
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
How about
=COUNTIFS(Table1[Date of Visit],">="&$AY$32,Table1[Date of Visit],"<="&$AY$33,Table1[Nurse name],$BA$31,index(Table1,0,Match($AY35,Table1[#Headers],0)),"No")
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,510
Messages
6,114,037
Members
448,543
Latest member
MartinLarkin

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