Intersection of table columns

jahsquare

Board Regular
Joined
Jan 22, 2014
Messages
51
Hi, I searched the forum but wasn't able to find an answer to my question:

If I have a table (formatted as a table) with the following data:

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]ID[/TD]
[TD]Boy[/TD]
[TD]Girl[/TD]
[TD]Human[/TD]
[TD]Adult[/TD]
[/TR]
[TR]
[TD]Jack[/TD]
[TD]1[/TD]
[TD][/TD]
[TD]1[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Jill[/TD]
[TD][/TD]
[TD]1[/TD]
[TD]1[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]Boaz[/TD]
[TD]1[/TD]
[TD][/TD]
[TD]1[/TD]
[TD]1[/TD]
[/TR]
</tbody>[/TABLE]

How can I generate the following table:
[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD][/TD]
[TD]Boy[/TD]
[TD]Girl[/TD]
[/TR]
[TR]
[TD]Human
[/TD]
[TD]Boaz
Jack
[/TD]
[TD]Jill[/TD]
[/TR]
[TR]
[TD]Adult[/TD]
[TD]Boaz[/TD]
[TD]Jill[/TD]
[/TR]
</tbody>[/TABLE]


Where the values are sorted and represent the column intersections from the source table.

Alternatively,
How could I generate this table:

BoyGirl
Human21
Adult11

<tbody>
</tbody>

Where selection of the numbers in the table would allow a user to access the corresponding list value from the table above (like a pivot table)? I am working with a large data set w/many columns so I would live to avoid using helper-columns if possible.

Thanks, just can't seem to figure this one out...
 
Last edited:

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Try this based on the Data in first table in thread, to give you the results in sheet 2, as per your second table.
NB:- You will need to show a more comprehensive set of data and your expected results, where you have multiple columns in a large data set.

Code:
[COLOR="Navy"]Sub[/COLOR] MG29Dec39
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, RngB [COLOR="Navy"]As[/COLOR] Range, nStr [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]String[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Txt [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]String,[/COLOR] RngC [COLOR="Navy"]As[/COLOR] Range, R [COLOR="Navy"]As[/COLOR] Range, Ac [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Set[/COLOR] Rng = Range("D2", Range("D" & Rows.Count).End(xlUp))
[COLOR="Navy"]Set[/COLOR] RngB = Range("B:B").SpecialCells(xlCellTypeConstants, 1)
[COLOR="Navy"]Set[/COLOR] RngC = Range("C:C").SpecialCells(xlCellTypeConstants, 1)
ReDim ray(1 To 3, 1 To 3)
ray(1, 2) = RngB(1).Offset(-1)
ray(1, 3) = RngB(1).Offset(-1, 1)
[COLOR="Navy"]For[/COLOR] Ac = 0 To 1
    [COLOR="Navy"]Set[/COLOR] Rng = Rng.Offset(, Ac).SpecialCells(xlCellTypeConstants, 1)
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
        [COLOR="Navy"]If[/COLOR] Not Intersect(Dn.EntireRow, RngB.EntireRow) [COLOR="Navy"]Is[/COLOR] Nothing [COLOR="Navy"]Then[/COLOR]
            ray(Ac + 2, 1) = Cells(1, Rng.Column)
            Txt = Range("A" & Intersect(Dn.EntireRow, RngB.EntireRow).Row).Value
            ray(Ac + 2, 2) = ray(Ac + 2, 2) & IIf(ray(Ac + 2, 2) = "", Txt, ", " & Txt)
        [COLOR="Navy"]End[/COLOR] If
            Txt = ""
        [COLOR="Navy"]If[/COLOR] Not Intersect(Dn.EntireRow, RngC.EntireRow) [COLOR="Navy"]Is[/COLOR] Nothing [COLOR="Navy"]Then[/COLOR]
            ray(Ac + 2, 1) = Cells(1, Rng.Column)
            Txt = Range("A" & Intersect(Dn.EntireRow, RngC.EntireRow).Row).Value
            ray(Ac + 2, 3) = ray(Ac + 2, 3) & IIf(ray(Ac + 2, 3) = "", Txt, ", " & Txt)
        [COLOR="Navy"]End[/COLOR] If
            Txt = ""
    [COLOR="Navy"]Next[/COLOR] Dn
[COLOR="Navy"]Next[/COLOR] Ac
[COLOR="Navy"]With[/COLOR] Sheets("Sheet2").Range("A1").Resize(UBound(ray, 1), UBound(ray, 2))
    .Value = ray
    .VerticalAlignment = xlCenter
    .Borders.Weight = 2
    .Columns.AutoFit
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]With[/COLOR]
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Last edited:
Upvote 0
Thanks for this, it works and I believe this can be adapted.

Here's an xlsx file with some actual data, and sample output (sheet 'Intersection map 1'). The output here is the result of an elaborate sumproduct formula with some data-validation filters applied from column A. Note that using 'Indirect()' allows me to just paste arbitrary lists of column headers from the main sheet into the X/Y axes of the output table.

What I need is a way to access the records from the Data sheet by interacting with the value cells in the "Intersection map 1" sheet. *

Either of these will work, but option A would be more flexible/ideal:

A) When the user selects a cell in the intersection map, a separate (live?) data table is populated with the corresponding list of records (similar to how you can double-click on a value in a pivot table to generate a new sheet showing a sub-table with matching records).

B) Get the ID numbers to the clipboard, the user can then paste them into another app to get the requested records. Easiest seems like generating a second map with the same format, where instead of numbers it has a concatenated list of all the IDs (as your example does). I can then just link the two tables so the user can quickly get the ID list.



Thanks again
 
Upvote 0
* to add - I think your solution could be adapted to work like option B, but I would ideally be able to input an arbitrary list of table column headers (or explicit column/row references as you have done). This will be reused in different areas of the same dataset (and across different datasets) so quickly being able to redefine the input parameters is key. My solution of using "indirect" and pasting col names between sheets could probably be improved also but it gets the job done.
 
Last edited:
Upvote 0
Sorry, disjointed thought trains here..

Is there a way I can just wrap the SUMPRODUCT fomula with CONCATENATE to show the IDs from the data table?

Something like =CONCATENATE(IF(SUMPRODUCT(...),1,0),Data1[ID])

where the SUMPRODUCT formula is:

=SUMPRODUCT(
--(INDIRECT("Data1["&D$1&"]")<>""),
--(INDIRECT("Data1["&$C2&"]")<>""),
--(INDIRECT("Data1["&$A$4&"]")<>""),
--(INDIRECT("Data1["&$A$7&"]")<>""),
--(INDIRECT("Data1["&$A$10&"]")<>""),
--(INDIRECT("Data1["&$A$13&"]")<>""),
--(INDIRECT("Data1["&$A$16&"]")<>""),
--(INDIRECT("Data1["&$A$19&"]")<>""),
--(INDIRECT("Data1[Year]")>=$A$23),
--(INDIRECT("Data1[Year]")<=$A$25)
)
 
Last edited:
Upvote 0
If you have one of the newer versions of Excel that has TEXTJOIN, you can use the formula in H2 for the list. The formula in L2 for the count should work in prior versions. If you don't have TEXTJOIN (or CONCAT), then you'll need some VBA code like Mick provided.

ABCDEFGHIJKLM

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
[TD="align: center"]1[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]ID[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Boy[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Girl[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Human[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Adult[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Boy[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Girl[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Boy[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Girl[/TD]

[TD="align: center"]2[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Jack[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"][/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"][/TD]
[TD="align: right"][/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Human[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Jack,Boaz[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Jill[/TD]
[TD="align: right"][/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Human[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]2[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]

[TD="align: center"]3[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Jill[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"][/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]
[TD="align: right"][/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Adult[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Boaz[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Jill[/TD]
[TD="align: right"][/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Adult[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]

[TD="align: center"]4[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] "]Boaz[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"][/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=FAFAFA]#FAFAFA[/URL] , align: right"]1[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

</tbody>
Sheet3

[TABLE="width: 85%"]
<tbody>[TR]
[TD]Array Formulas[TABLE="width: 100%"]
<thead>[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]
[TH="width: 10px"]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
</thead><tbody>[TR]
[TH="width: 10px, bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]H2[/TH]
[TD="align: left"]{=TEXTJOIN(",",TRUE,IF(INDEX($A$1:$E$4,0,MATCH(H$1,INDEX($A$1:$E$4,1,0),0))=1,IF(INDEX($A$1:$E$4,0,MATCH($G2,INDEX($A$1:$E$4,1,0),0))=1,INDEX($A$1:$E$4,0,1),""),""))}[/TD]
[/TR]
[TR]
[TH="width: 10px, bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]L2[/TH]
[TD="align: left"]{=SUM(IF(INDEX($A$1:$E$4,0,MATCH(L$1,INDEX($A$1:$E$4,1,0),0))=1,IF(INDEX($A$1:$E$4,0,MATCH($G2,INDEX($A$1:$E$4,1,0),0))=1,1)))}[/TD]
[/TR]
</tbody>[/TABLE]
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself[/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
Eric W, thanks for the reply. I'm looking to see if I can adapt this to my situation. Would it be possible to wrap my existing SUMPRODUCT formula in TEXTJOIN or CONCATENATE as noted above?
 
Upvote 0
* apparently office 2016 doesn't have textjoin (365 only). So I will have to use CONCATENATE (preferably) or VBA
 
Upvote 0
CONCATENATE doesn't handle arrays. So unless you want to list every single cell from your source table in the formula, it won't work. About the only non-VBA way to do this is to create a helper column for EVERY cell in your output table. Pretty ugly. Better to stick with VBA in this case.
 
Upvote 0
Thanks. Yeah the helper columns are going to be more trouble than they're worth... I actually have a subscription to 365 but had 2016 installed out of laziness... I think this is worth a reinstall!
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,240
Members
452,621
Latest member
Laura_PinksBTHFT

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