Search Filter Mapping Matrix - via VBA code

ShuStar

Board Regular
Joined
Sep 9, 2015
Messages
89
Office Version
  1. 2010
Platform
  1. Windows
Hi all,

Really need some support in figuring out how to do this. Any help would be greatly appreciated.

Unfortunately I'm having issues with XL2BB, but in the meantime my excel workbook can be found on this google drive link: Excel - Google Drive

Mapping Filter WorkBook


Context:
In the raw data tab there are Names matched against Fruits which people enjoy. Y is for yes. N is for No.
The Keyword Tab is shortlisted words from the Raw Data Tab - this is static and manually inputted.
Matrix tab - based on the ask below, the mapping is to be plotted here.

The ask:
For each fruit in the Keyword tab, I would like for the VBA code to scan this list cell by cell and match it to any names where it is marked Y in the Raw Data tab; then plot this in the Matrix tab.

Notes:
A - In the keywords tab, they words will always be in Column B, however rows are not fixed; in the example there are 7 words in Column B but sometimes this could be 3 or even 10 or 100 - it depends if the columns in raw data tab increase too; if a fixed range needs to be provided then 500 rows would be a safe bet to fix it at.
B - In the Matrix tab, it should only contain the Names which are impacted by any of the key words (ie not all the names or fruits from Raw Data tab should be included)
C - not looking to resolve this by a Vlookup/Index Match - has to be done by VBA code I'm afraid

Any help in figuring out how this should be would be greatly appreciated (I got stuck trying to create the loop etc).

In the link contains my code but I think I have lost myself - basically i was trying to match the keywords and then do a filter somehow.. nevermind, will hopefully get better with more practice.. probably worth ignoring...
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
How about
VBA Code:
Sub ShuStar()
   Dim KeyAry As Variant, DataAry As Variant, OutAry As Variant
   Dim r As Long, nr As Long, c As Long
   Dim nc As Variant
   Dim Flg As Boolean
   
   With Sheets("Keywords")
      KeyAry = Application.Transpose(.Range("B3", .Range("B" & Rows.Count).End(xlUp)).Value2)
   End With
   DataAry = Sheets("Raw Data").Range("A2").CurrentRegion.Value2
   ReDim OutAry(1 To UBound(DataAry), 1 To UBound(KeyAry) + 2)
   
   For r = 2 To UBound(DataAry)
      For c = 2 To UBound(DataAry, 2)
         nc = Application.Match(DataAry(1, c), KeyAry, 0)
         If Not IsError(nc) And DataAry(r, c) = "Y" Then
            If Not Flg Then
               nr = nr + 1
               Flg = True
               OutAry(nr, 1) = DataAry(r, 1)
            End If
            OutAry(nr, nc + 2) = DataAry(r, c)
         End If
      Next c
      Flg = False
   Next r
   With Sheets("Matrix")
      .UsedRange.ClearContents
      .Range("A2:b2").Value = Array("Names", "Count")
      .Range("C2").Resize(, UBound(KeyAry)).Value = KeyAry
      .Range("A3").Resize(nr, UBound(OutAry, 2)).Value = OutAry
   End With
End Sub
 
Upvote 0
Thank you so much! This is working as expected!

Is there a way to include the Countif into the code? Effectively to count the Y's in the matrix column?
 
Upvote 0
How about
VBA Code:
Sub ShuStar()
   Dim KeyAry As Variant, DataAry As Variant, OutAry As Variant
   Dim r As Long, nr As Long, c As Long, Cnt As Long
   Dim nc As Variant
   Dim Flg As Boolean
   
   With Sheets("Keywords")
      KeyAry = Application.Transpose(.Range("B3", .Range("B" & Rows.Count).End(xlUp)).Value2)
   End With
   DataAry = Sheets("Raw Data").Range("A2").CurrentRegion.Value2
   ReDim OutAry(1 To UBound(DataAry), 1 To UBound(KeyAry) + 2)
   
   For r = 2 To UBound(DataAry)
      For c = 2 To UBound(DataAry, 2)
         nc = Application.Match(DataAry(1, c), KeyAry, 0)
         If Not IsError(nc) And DataAry(r, c) = "Y" Then
            If Not Flg Then
               nr = nr + 1
               Flg = True
               OutAry(nr, 1) = DataAry(r, 1)
            End If
            Cnt = Cnt + 1
            OutAry(nr, nc + 2) = DataAry(r, c)
         End If
      Next c
      If Flg Then OutAry(nr, 2) = Cnt
      Cnt = 0
      Flg = False
   Next r
   With Sheets("Matrix")
      .UsedRange.ClearContents
      .Range("A2:b2").Value = Array("Names", "Count")
      .Range("C2").Resize(, UBound(KeyAry)).Value = KeyAry
      .Range("A3").Resize(nr, UBound(OutAry, 2)).Value = OutAry
   End With
End Sub
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0
Hi - sorry to come back to this.

I'm getting a runtime error '1004' - Aplication defined or object-defined error. And upon clicking debug it makes this code row yellow:

.Range("A3").Resize(nr, UBound(OutAry, 2)).Value = OutAry
End With


Do you know why this could be the case or how i can resolve? It works fine in the sample example I gave, but when i take it to my main sheet its not working - however my main sheet is exactly the same as the sample example...
 
Upvote 0
That line shouldn't cause any problems, have you made any changes to the code?
 
Upvote 0
Ahh i realise why.

In my Main Worksheet Raw Data Tab - there is a small line of text in A1 - this wasn't in the sample sheet - my bad. When I clear the cell in A1 in my main raw data sheet, the code is now working as the way you provided it.

Thank you.
 
Upvote 0
Is there a way to adapt the code so it ignores or skips if there's any text in A1 in the Raw Data Tab without breaking the code?

For extracts I will export, text being in A1 in the raw data tab is 50/50 - this text is dependent on the type of extract exported. There isn't any more text to be placed anywhere else (ie randomly in C1 or D1)
 
Upvote 0

Forum statistics

Threads
1,213,489
Messages
6,113,949
Members
448,534
Latest member
benefuexx

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