VBA help to import/export list of data to populate a grid

ItalianPlatinum

Well-known Member
Joined
Mar 23, 2017
Messages
793
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Hello - I couldn't find anything to uniquely accomplish what I am ultimately trying to do.
  1. I have a grid of data where column A7 down is my account #
  2. Starting at O6 to no end zz6 say for sake of argument where the accounts are grouped by a group #
  3. Currently I manually update the grid to place an X if the account is in the group #
    1. my file is going to grow exponentially so I can no longer manually support
Looking for a way in another tab to just list group #, Account #, then Add or remove then it will update the grid to clear X's if removed or add X if adding. For example below is a mocked up grid.

Book1
ABCDEFGHIJKLMNOPQRSTUVW
1Count102264102106
2PurposeTrackinglabelshipNeedsXXXXXXXXXXXXXXX
3OwnerTeam 1Team 1Team 1Team 1Team 1Team 1Team 1Team 1Team 1
4UniqueUniqueBasicUniqueBasicUniqueBasicUniqueBasicBasic
5AccountDesc 1Desc 2Account #NameFillerFillerFillerFillerFillerFillerFillerFillerFillerGroup 1Group 2Group 3Group 4Group 5Group 6Group 7Group 8Group 9
6100002000030000400005000060000700008000090000
71LargeL1XX1JNANANANANANANANANAXXXXXXX
82LargeL2XX2MNANANANANANANANANAXXXXXXX
93LargeL3XX3LNANANANANANANANANAXXXXXX
104LargeL4XX4ONANANANANANANANANAXXXXXX
115MediumL5XX5PNANANANANANANANANAXXXXX
126MediumL6XX6QNANANANANANANANANAXXXXX
137MediumL7XX7RNANANANANANANANANAXXXX
148SmallL8XX8SNANANANANANANANANAXXXX
159SmallL9XX9TNANANANANANANANANAXXXX
1610SmallL10XX10UNANANANANANANANANAXXXX
Grid
Cell Formulas
RangeFormula
O1:W1O1=COUNTA(O7:O10000)
 
So, do not clear in success and just fill the Result-column by "success", "already exists", "no X's exist to remove"?
 
Upvote 0

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Try:
VBA Code:
Sub UpdateGrid()

  Const DataCell = "O7"
  Dim ShGrid As Worksheet, ShImpExp As Worksheet
  Dim Rng As Range
  Dim DicAcc As Object, DicGrp As Object
  Dim Acc As Variant, Grp As Variant
  Dim a() As Variant, Data() As Variant
  Dim i As Long
  Dim s As String, s1 As String

  Set ShGrid = Sheets("Grid")
  Set ShImpExp = Sheets("ImportExport")

  ' Create dictionaries for accounts and groups
  Set DicAcc = CreateObject("Scripting.Dictionary")
  Set DicGrp = CreateObject("Scripting.Dictionary")
  DicAcc.CompareMode = 1
  DicGrp.CompareMode = 1

  With ShGrid.Range("A1").CurrentRegion

    ' Copy Grid X's data to the Data()
    Set Rng = .Range(DataCell).Resize(.Rows.Count - .Range(DataCell).Row + 1, .Columns.Count - .Range(DataCell).Column + 1)
    Data() = Rng.Value

    ' Put accounts and their rows to the dictionary
    a() = Rng.EntireRow.Columns(1).Value ' Replace 1 by 4 to use D-column in Grid instead of A-column
    For i = 1 To UBound(a)
      DicAcc.Item(a(i, 1)) = i
    Next

    ' Put groups and their columns to the dictionary
    a() = Rng.Offset(-1).Value
    For i = 1 To UBound(a, 2)
      DicGrp.Item(a(1, i)) = i
    Next

  End With

  ' Main
  a() = ShImpExp.UsedRange.Resize(, 4).Value
  For i = 2 To UBound(a)
    s = UCase(Trim(a(i, 1)))  ' "A" to add or "R" to remove
    Grp = a(i, 2)             ' Group
    Acc = a(i, 3)             ' Account
    a(i, 4) = Empty           ' Result
    If Len(Trim(Grp)) > 0 And Len(Trim(Acc)) > 0 Then
      If Not (s = "A" Or s = "R") Then
        ShImpExp.Cells(i, 1).Select
        MsgBox "Wrong code - '" & s & "'" & vbLf & "Use 'A' to add 'X' to Grig" & vbLf & "Use 'R' to remove 'X' from Grid", vbExclamation, "Exit"
        Exit Sub
      End If
      If Not DicGrp.Exists(Grp) Then
        ShImpExp.Cells(i, 2).Select
        MsgBox "Group '" & Grp & "' not found in the Grig", vbExclamation, "Exit"
        Exit Sub
      End If
      If Not DicAcc.Exists(Acc) Then
        ShImpExp.Cells(i, 3).Select
        MsgBox "Account '" & Acc & "' not found in the Grig", vbExclamation, "Exit"
        Exit Sub
      End If
      ' Update the intersected Account-Group value in the Data()
      If s = "A" Then s = "X" Else s = ""
      s1 = UCase(Data(DicAcc.Item(Acc), DicGrp.Item(Grp)))
      If s = s1 Then
        If s = "X" Then
          a(i, 4) = "already exists"
        Else
          a(i, 4) = "no X's exist to remove"
        End If
      Else
        Data(DicAcc.Item(Acc), DicGrp.Item(Grp)) = s
        a(i, 4) = "success"
      End If
    End If
  Next

  ' Update ImportExport
  ShImpExp.UsedRange.Resize(, 4).Value = a()
  
  ' Update Grig
  Rng.Value = Data()

  ' Release memory of the object variables
  Set DicAcc = Nothing
  Set DicGrp = Nothing

End Sub
 
Upvote 0
I like this a lot more than the dialog box. Could that results column be a source of all errors/messaging? For example: account doesn't exist or group doesn't exist. just present it there.

Also one minor thing. if R is successful could it have its own. example A = successfully Added; R = Successfully removed.
 
Upvote 0
VBA Code:
Sub UpdateGrid()

  Const DataCell = "O7"
  Dim ShGrid As Worksheet, ShImpExp As Worksheet
  Dim Rng As Range
  Dim DicAcc As Object, DicGrp As Object
  Dim Acc As Variant, Grp As Variant
  Dim a() As Variant, Data() As Variant
  Dim i As Long
  Dim s As String, s1 As String

  Set ShGrid = Sheets("Grid")
  Set ShImpExp = Sheets("ImportExport")

  ' Create dictionaries for accounts and groups
  Set DicAcc = CreateObject("Scripting.Dictionary")
  Set DicGrp = CreateObject("Scripting.Dictionary")
  DicAcc.CompareMode = 1
  DicGrp.CompareMode = 1

  With ShGrid.Range("A1").CurrentRegion

    ' Copy Grid X's data to the Data()
    Set Rng = .Range(DataCell).Resize(.Rows.Count - .Range(DataCell).Row + 1, .Columns.Count - .Range(DataCell).Column + 1)
    Data() = Rng.Value

    ' Put accounts and their rows to the dictionary
    a() = Rng.EntireRow.Columns(1).Value ' Replace 1 by 4 to use D-column in Grid instead of A-column
    For i = 1 To UBound(a)
      DicAcc.Item(a(i, 1)) = i
    Next

    ' Put groups and their columns to the dictionary
    a() = Rng.Offset(-1).Value
    For i = 1 To UBound(a, 2)
      DicGrp.Item(a(1, i)) = i
    Next

  End With

  ' Main
  a() = ShImpExp.UsedRange.Resize(, 4).Value
  For i = 2 To UBound(a)
    s = UCase(Trim(a(i, 1)))  ' "A" to add or "R" to remove
    Grp = a(i, 2)             ' Group
    Acc = a(i, 3)             ' Account
    a(i, 4) = Empty           ' Result
    If Len(Trim(Grp)) > 0 And Len(Trim(Acc)) > 0 Then
      If Not (s = "A" Or s = "R") Then a(i, 4) = "Wrong 'A'/'R' code"
      If Not DicGrp.Exists(Grp) Then a(i, 4) = IIf(Len(a(i, 4)) > 0, a(i, 4) & ", ", "") & "Group doesn't exist"
      If Not DicAcc.Exists(Acc) Then a(i, 4) = IIf(Len(a(i, 4)) > 0, a(i, 4) & ", ", "") & "Account doesn't exist"
      ' Update the intersected Account-Group value in the Data()
      If s = "A" Then s = "X" Else s = ""
      If Len(a(i, 4)) = 0 Then
        s1 = UCase(Data(DicAcc.Item(Acc), DicGrp.Item(Grp)))
        If s = s1 Then
          If a(i, 1) = "A" Then
            a(i, 4) = "Already exists"
          ElseIf a(i, 1) = "R" Then
            a(i, 4) = "No X's exist to remove"
          End If
        Else
          Data(DicAcc.Item(Acc), DicGrp.Item(Grp)) = s
          a(i, 4) = "Successfully " & IIf(s = "X", "addeed", "removed")
        End If
      End If
    End If
  Next

  ' Update ImportExport
  ShImpExp.UsedRange.Resize(, 4).Value = a()
  
  ' Update Grig
  Rng.Value = Data()

  ' Release memory of the object variables
  Set DicAcc = Nothing
  Set DicGrp = Nothing

End Sub
 
Upvote 0
This is working great Vlad. I will promote it to my real data today to see. Thank you so much. I will let you know how it works. But so far its very awesome.
 
Upvote 0
Vlad so one thing that I am noticing. If I have a filter set on the grid. the messaging says it added or removed even though it doesn't add or remove the Xs. but if I remove the filter on the grid and run it works fine and generates messages correctly. Do I need to embedded in an autofilter off then back off in the process or can the code recognize if a filter is set and still operate regardless
 
Upvote 0
Code should not depend on a filter of the Grig.
Try filtering data of your example in the post #1.
And if problem exists then let me know where is the filter and its criteria.
 
Last edited:
Upvote 0
BTW, code expects that there are no empty rows in the Grid's table like it's shown in the post #1.
 
Upvote 0
Still same issue tried it on my smaller test subject. filter is set on row 6. and the filter criteria could change depending on user.
 
Upvote 0

Forum statistics

Threads
1,214,938
Messages
6,122,346
Members
449,080
Latest member
Armadillos

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