Reverse lookup returning multiple column headers to a single cell

Paperless

New Member
Joined
Jul 18, 2017
Messages
4
Hi everyone,

I am trying to do a reverse lookup to return column headers by matching the data items within a grid list.

Currently, I am facing a difficulty in returning multiple column headers (Sheet 1) and they should be returned to a single cell in the "Interface Sheet".

Interface Sheet Example:

___A____| _____B
1 Query__|_Query data field
2 TEST01 | Customer ID, Gender, Address, Age
3 TEST02 | Customer ID, Gender, Martial Status
4 TEST03 | Customer ID, Phone Number, Age
5 TEST04 | Gender, Address, Age

Sheet 1 Example:

____A___________B___________C___________D__________E___________F__________G
1 __S/N______Customer ID____Gender___Phone Number__Address____Marital Status____Age
2 TEST01-1_____TEST01______TEST01_________________TEST01__________________TEST01
3 TEST02-1_____TEST02______TEST02_____________________________TEST02
4 TEST03-1_____TEST03_________________TEST03______________________________TEST03
5 TEST04-1_________________TEST04_________________TEST04__________________TEST04

In Interface Sheet, cells B2 to B5 contains the lookup formula to return column headers from Sheet 1 as expressed in the examples. To make it simple, under query "TEST01" in the Interface Sheet, cell B2 should be able to return all the column headers from Sheet 1 that contains "TEST01" in each respective column and fit them all in cell B2.

Any lookup formulas are fine with me as long as it can solve the problem!
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.
In B2 of Interface control+shift+enter, not just enter, and copy down:

=TEXTJOIN(",",TRUE,IF(INDEX(Sheet1!$B$2:$G$5,MATCH(A2&"*",Sheet1!$A$2:$A$5,0),0)<>"",Sheet1!$B$1:$G$1,""))

If you don't have TEXTJOIN on your system, we can use ACONCAT, a user-defined function.
 
Upvote 0
Unfortunately, my system does not consist of TEXTJOIN in its formula as it is the 2010 version.

Is there an alternative besides ACONCAT in solving this? I would like to keep it VBA free.
 
Upvote 0
Unfortunately, my system does not consist of TEXTJOIN in its formula as it is the 2010 version.

Is there an alternative besides ACONCAT in solving this? I would like to keep it VBA free.

Not that I know of, but I guess you are calling for others chime in.
 
Upvote 0
Can you use something like this? This would be a 2 step process. I essentially mirrored your example. Assume your sheet1 range is A1:G8. I entered a criteria (Test01) in I1. I placed my first formula in J1. I used the =iferror(.....)," ") to clear error messages after you get all your results. Then you would select the actual result range. In J1 I used =
=IFERROR(INDEX($B$1:$G$1,SMALL(IF($B$2:$G$5=$I$1,COLUMN($B$2:$G$5)-COLUMN($B$2)+1),ROWS($J$1:J1)))," ") You need to use Cntrl+Shift+Enter. Copy down. The results for Test01 is four items. So you would use the range J1:J4 for the second formula.

I put the second formula in K1. The formula is =concatenate(transpose(J1:J4&",")) Before you hit enter, highlight the transpose(.....) with your mouse. Hit F9 and remove the { and }. Then enter. Hope this helps

<tbody>
</tbody>
 
Upvote 0
Sorry. forgot to send your my data example.

NoIDGenderPhoneAddressStatusAgeTest01 Test01ID,Gender,Address,Age,
Test01-1Test01Test01Test01Test01Gender
Test02-1Test02Test02Test02Address
Test03-1Test03Test03Age
Test07-1Test04Test04Test04

<colgroup><col><col><col><col><col span="7"><col></colgroup><tbody>
</tbody>
 
Upvote 0
Can you use something like this? This would be a 2 step process. I essentially mirrored your example. Assume your sheet1 range is A1:G8. I entered a criteria (Test01) in I1. I placed my first formula in J1. I used the =iferror(.....)," ") to clear error messages after you get all your results. Then you would select the actual result range. In J1 I used =
=IFERROR(INDEX($B$1:$G$1,SMALL(IF($B$2:$G$5=$I$1,COLUMN($B$2:$G$5)-COLUMN($B$2)+1),ROWS($J$1:J1)))," ") You need to use Cntrl+Shift+Enter. Copy down. The results for Test01 is four items. So you would use the range J1:J4 for the second formula.

I put the second formula in K1. The formula is =concatenate(transpose(J1:J4&",")) Before you hit enter, highlight the transpose(.....) with your mouse. Hit F9 and remove the { and }. Then enter. Hope this helps

<tbody>
</tbody>

This is what I wanted but is it possible to customise the IFERROR(...) formula to be dragged across horizontally i.e. J1:M1 instead of vertically J1:J4?

The problem will be solved if it can be done. Thank you!
 
Upvote 0
So you abandon the single cell goal... In that case:

In B2 of interface control+shift+enter, not just enter, copy across, and down:

=IFERROR(INDEX(Sheet1!$B$1:$G$1,SMALL(IF(INDEX(Sheet1!$B$2:$G$5,MATCH($A2&"*",Sheet1!$A$2:$A$5,0),0)=$A2,COLUMN(Sheet1!$B$1:$G$1)-COLUMN(Sheet1!$B$1)+1),COLUMNS($B2:B2))),"")
 
Upvote 0
So you abandon the single cell goal... In that case:

In B2 of interface control+shift+enter, not just enter, copy across, and down:

=IFERROR(INDEX(Sheet1!$B$1:$G$1,SMALL(IF(INDEX(Sheet1!$B$2:$G$5,MATCH($A2&"*",Sheet1!$A$2:$A$5,0),0)=$A2,COLUMN(Sheet1!$B$1:$G$1)-COLUMN(Sheet1!$B$1)+1),COLUMNS($B2:B2))),"")

It perfectly solve my problem. My apology if I did not articulate my idea well on the single cell. I figured out that I can drag the formulas across horizontally and use a manual function but still dynamic to combine the results into one cell. All these formulas will be contained inside a working sheet and become hidden, and use a lookup function to return it to the main sheet.

Nonetheless, thank you Aladin and Mike so much for the help! :)
 
Upvote 0

Forum statistics

Threads
1,214,979
Messages
6,122,560
Members
449,089
Latest member
Motoracer88

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