Forum Discussion
Finding the column name for a value in a table
- Nov 17, 2018
That helps, thanks :)
What if I want to expand the table with more columns and rows? Is it possible to make the formula more dynamic?
- John_BainbridgeJan 28, 2024Copper ContributorThe problem we have here is that we are assuming that there will be no repeat values. As soon as there are then the column numbers will be added which gives the wrong result. Enter "38" into A7 for example and you will return Third (1+2).
- SergeiBaklanJan 29, 2024Diamond Contributor
Too old thread...
Yes, you are right, it is assumed we have unique values. For the modern Excel PeterBartholomew1 gave the solution above. For the legacy Excel to return first column where the value appears it could be like
=IFERROR( INDEX( $A$1:$C$1, AGGREGATE( 15, 6, 1 / ($A$2:$C$15 = $E$1) * COLUMN($A$2:$C$15), 1 ) ), "no such" )
To show few columns with the target value it could be
=IFERROR( INDEX( $A$1:$C$1, AGGREGATE( 15, 6, 1 / ($A$2:$C$15 = $E$1) * COLUMN($A$2:$C$15), COLUMN()-COLUMN($J$1)+1 ) ), "" )
and drag it to the right till first empty cell appear.
- AZUBHANJul 11, 2023Copper Contributor
IF value is in one or more than cells than i want to show all the column name that have value
- PeterBartholomew1Jul 11, 2023Silver Contributor
If you want the result as a comma separated list you could use
= TEXTJOIN(", ",,IF(data = searchCriterion, header, ""))
To obtain a list
= TOCOL(IF(data = searchCriterion, header, NA()),3)
Each formula tests every cell of the data table and uses a function to filter the results.
- swstr510May 23, 2021Copper Contributor
please help me out, i need a formula to select coloumn name, on basis of finding the min value .
i need a formula to selection-1 and selction-2 for selecting vendor with min values
place vendor-1 vendor-2 vendor-3 vendor-4 selection-1 selection-2 USA 5000 7000 5000 8000 vendor-1 vendor-3 INdia 9000 8000 8000 9500 vendor-2 vendor-3 - Peter JohanssonNov 17, 2018Copper Contributor
Thanks,
That works like a charm :) Let's say these numbers were part of a zip code.
So in E1 I would enter 38000. Instead of the part: $A$2:$C$15=$E$1
I'd like: $A$2:$C$15=LEFT($E$1;2)
But I get a #REF! error. What can be wrong in this case?- SergeiBaklanNov 17, 2018Diamond Contributor
Peter, LEFT returns text, wrap it with VALUE to receive number
=OFFSET($A$1,0,SUMPRODUCT(($A$2:$C$15=VALUE(LEFT($E$2,2)))*COLUMN($A$2:$C$15))-1)
- Peter JohanssonNov 17, 2018Copper Contributor
Works great. Thanks again :)