Find Column Header By Name/Reference and Dynamically Extract Name of Rows with an 'X'

Eduard_Stoo

New Member
Joined
Apr 15, 2024
Messages
4
Office Version
  1. 365
Platform
  1. Windows
Hi -

I've got close a few times with this but just can't nail it... I am wanting to populate sheets for staff that pull through their relevant job tasks based on: their job title as named in a column, and an 'X' where it applies to them. However, I want to extract the task name, not the 'X' itself, so there's a slight adjust to the column reference required. I've tried Index/Match, Filter and some other combinations, but can't quite get that sweet spot! Could anyone please guide me on this? Thanks
 

Attachments

  • Screenshot 2024-04-15 095026.png
    Screenshot 2024-04-15 095026.png
    47.5 KB · Views: 11

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
=INDEX($B$2:$AA$2,SUMPRODUCT(MAX(($B$4:$AA$69=B103)*(COLUMN($B$4:$AA$69))))-COLUMN(B35)+1)

I use this on my sheet to extract column and row headers, I'm not sure if you can adjust where appropriate or it may open some doors for you to amend where you see fit.

Not sure how it would work for x in a box as they are all matching data and excel wouldn't be able to define each instance
 
Upvote 0
Thanks, I've given it a go but can't quite get it singing...

The "X" should trigger a check against the value in Column A, which is unique so should mean you can make unique references to the left?
 
Upvote 0
Hi & welcome to MrExcel.
How about
Excel Formula:
=FILTER(A3:A100,CHOOSECOLS(C3:G100,XMATCH(J3,C3:G3))="x")
 
Upvote 0
I had

=IFERROR(INDEX($A$3:A$8,AGGREGATE(15,6,ROW($A$3:$A$8)/(INDIRECT("$"&MID("CDEFG",MATCH($J$3,$C$2:$J$2,0),1)&"$3:$"&MID("CDEFG",MATCH($J$3,$C$2:$J$2,0),1)&"$8")="x"),ROWS($A$3:A3))-(3-1),COLUMNS($A1:A1)),"")
 
Upvote 0
Thanks, got that working - I had to XMATCH to C2:G2 not C3:G3 as it's matching the header name, hope that's right. It only works as an array formula too, I think that's how the FILTER formula works if memory serves...
 
Upvote 0
Thanks Fluff - I am actually fetching this data from another tab. If I just use the formula as standard it just 'SPILL!'s and doesn't populate, however if I array it, it works just fine?

It is actually in this form, and the real sheet is much larger.
=IFERROR(FILTER('Training Record Tasks List'!C3:C104,CHOOSECOLS('Training Record Tasks List'!$E$3:$AE$104,XMATCH($AB$1,'Training Record Tasks List'!$E$2:$AE$2))="X"),""). I've had to mess with some of the 'absolute references' in places, otherwise it only pulls through one entry, or doesn't work, or spills. This combination works OK though!!
 
Upvote 0
Do NOT use Ctrl Shift Enter.
Clear all the cells below the formula & enter it normally.
 
Upvote 0

Forum statistics

Threads
1,215,334
Messages
6,124,321
Members
449,154
Latest member
pollardxlsm

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