Feeding through to a Summary Tab

Excel_77

Active Member
Joined
Sep 15, 2016
Messages
311
Office Version
  1. 2019
Platform
  1. Windows
Hi All,

I have a "Summary" tab that records a list of subject in column B2 onwards, in Column C1-E1 there are heading with peoples names that relate to my three sub tabs, the sub are named "David," "Mike" and "Susan".

So in C2 of the "Summary" tab, I want to look at the subject in column B, then go to the tab called "David", match the subject in column G and return the corresponding value in column H of tab "David".

Is this possible and if so how?

Thanks in advance
 
If you remove the IFERROR() wrapper what is the error that is being returned?

EDIT: Maybe if you wait until tomorrow it will start working ;)

Haha I think I have found the problem but I don't think there is a solution. I stated originally that I wanted to return column C which is the "Comments" column, however in various tabs this appears in different locations, for example in one tab it is within column Q. I presume there is no solution to this?
 
Upvote 0

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
Does the "Comments" column have a common header that is the same across all the sheets and in the same row of all the sheets?
 
Upvote 0
Does the "Comments" column have a common header that is the same across all the sheets and in the same row of all the sheets?

Always called "Comments" and always within row 1 of the sub tabs.
 
Upvote 0
Always called "Comments" and always within row 1 of the sub tabs.

Is the lookup column (column B) always the same column or does that change as well?

I'm asking because after thinking about it the comments column not being in column C wouldn't necessarily be the cause of the error as you'd just end up returning the value from column C rather than the value from the comments column.
 
Upvote 0
Is the lookup column (column B) always the same column or does that change as well?

I'm asking because after thinking about it the comments column not being in column C wouldn't necessarily be the cause of the error as you'd just end up returning the value from column C rather than the value from the comments column.

Good point and no the look-up column is not always in B, but it's always called "Subject".
 
Upvote 0
it's always called "Subject".
- I'm assuming it's always in row 1 as well.

Try this, note that it returns a blank instead of "No" if there is a match but the comments column doesn't contain a value.

Code:
=IFERROR(T(INDEX(INDIRECT("'"&F$2&"'!A:ZZ"),MATCH($B3,INDEX(INDIRECT("'"&F$2&"'!A:ZZ"),0,MATCH("Subject",INDIRECT("'"&F$2&"'!A1:ZZ1"),0)),0),MATCH("Comments",INDIRECT("'"&F$2&"'!A1:ZZ1"),0))),"Error")
 
Last edited:
Upvote 0
- I'm assuming it's always in row 1 as well.

Try this, note that it returns a blank instead of "No" if there is a match but the comments column doesn't contain a value.

Code:
=IFERROR(T(INDEX(INDIRECT("'"&F$2&"'!A:ZZ"),MATCH($B3,INDEX(INDIRECT("'"&F$2&"'!A:ZZ"),0,MATCH("Subject",INDIRECT("'"&F$2&"'!A1:ZZ1"),0)),0),MATCH("Comments",INDIRECT("'"&F$2&"'!A1:ZZ1"),0))),"Error")

Perfect, for instances where the comment column doesn't contain a value can "NA" be returned instead of a blank?
 
Upvote 0
instances where the comment column doesn't contain a value can "NA" be returned instead of a blank?

If you want the NA to be physically in the cell you would need to do the same IF() type test we did before which gets a bit cumbersome - but you could achieve the same look by trying this:

Code:
=IFERROR(INDEX(INDIRECT("'"&F$2&"'!A:ZZ"),MATCH($B3,INDEX(INDIRECT("'"&F$2&"'!A:ZZ"),0,MATCH("Subject",INDIRECT("'"&F$2&"'!A1:ZZ1"),0)),0),MATCH("Comments",INDIRECT("'"&F$2&"'!A1:ZZ1"),0)),"Error")

And then custom formatting the cells that contain the formula with:

Code:
;;"NA"
 
Upvote 0
If you want the NA to be physically in the cell you would need to do the same IF() type test we did before which gets a bit cumbersome - but you could achieve the same look by trying this:

Code:
=IFERROR(INDEX(INDIRECT("'"&F$2&"'!A:ZZ"),MATCH($B3,INDEX(INDIRECT("'"&F$2&"'!A:ZZ"),0,MATCH("Subject",INDIRECT("'"&F$2&"'!A1:ZZ1"),0)),0),MATCH("Comments",INDIRECT("'"&F$2&"'!A1:ZZ1"),0)),"Error")

And then custom formatting the cells that contain the formula with:

Code:
;;"NA"

I tried
Code:
=IFERROR(INDEX(INDIRECT("'"&F$2&"'!A:ZZ"),MATCH($B3,INDEX(INDIRECT("'"&F$2&"'!A:ZZ"),0,MATCH("Subject",INDIRECT("'"&F$2&"'!A1:ZZ1"),0)),0),MATCH("Comments",INDIRECT("'"&F$2&"'!A1:ZZ1"),0)),"Error")

It works but returns 0 where I want "NA". I am not certain on how this can be made custom. We are painfully close to finishing this at present.
 
Upvote 0
It works but returns 0 where I want "NA". I am not certain on how this can be made custom. We are painfully close to finishing this at present.

Highlight the cells that contain the formula | press CTRL+1 | Select "Custom" from the "Category" list on the "Number" tab | in the "Type" text box enter ;;"NA" | Click OK
 
Upvote 0

Forum statistics

Threads
1,224,828
Messages
6,181,201
Members
453,022
Latest member
RobertV1609

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