Scripting Dictionary Kicking my Behind

reberryjr

Well-known Member
Joined
Mar 16, 2017
Messages
701
Office Version
  1. 365
Platform
  1. Windows
If the underlying scenario is true, then I want the value in column I to map over to column Q. I've been looking online, and at past dictionaries I've received help on, but I can't seem to figure out where I'm going wrong.

1689076600812.png



VBA Code:
Sub IQR_Calcs()
Application.DisplayAlerts = False
Application.ScreenUpdating = False
Dim m As Workbook
Dim mI As Worksheet, mM As Worksheet, mD As Worksheet, mO As Worksheet, mP As Worksheet, mV As Worksheet
Dim mILR As Long, mMLR As Long, mDLR As Long, mOLR As Long, mPLR As Long, mVLR As Long, i As Long
Dim Rng As Range
Dim Dic As Object
Set m = ThisWorkbook
Set mI = m.Sheets("CC_IQR")
Set mM = m.Sheets("CC_MC")
Set mD = m.Sheets("CC_MD")
Set mO = m.Sheets("ORC_PAR")
Set mP = m.Sheets("PRF")
Set mV = m.Sheets("Variables")
mILR = mI.Range("A" & Rows.Count).End(xlUp).Row
mMLR = mM.Range("A" & Rows.Count).End(xlUp).Row
mDLR = mD.Range("A" & Rows.Count).End(xlUp).Row
mOLR = mO.Range("A" & Rows.Count).End(xlUp).Row
mPLR = mP.Range("A" & Rows.Count).End(xlUp).Row
mVLR = mV.Range("A" & Rows.Count).End(xlUp).Row
'Identify the VTC start date.
Set Dic = CreateObject("Scripting.Dictionary")
For Each Rng In mI.Range("A2", mI.Range("A" & mI.Rows.Count).End(xlUp))
If Not Dic.exists(Rng.Value & Rng.Offset(0, 11)) Then
Dic.Add Rng.Value & Rng.Offset(0, 11), Nothing
End If
Next
For Each Rng In mD.Range("A2", mD.Range("A" & mD.Rows.Count).End(xlUp))
If Dic.exists(Rng.Value & Rng.Offset(0, 7)) Then
mD.Range("I" & Rng.Row).Copy
mI.Range("Q" & Rng.Row).PasteSpecial xlPasteValues
Else
If Not Dic.exists(Rng.Value & Rng.Offset(0, 11)) Then
mI.Range("Q" & Rng.Row) = "Review"
End If
End If
Next
Dic.RemoveAll
Application.ScreenUpdating = True
Application.DisplayAlerts = True
End Sub
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
I hope this helps:
VBA Code:
Sub test()
  Dim mDdict As Object, mIRange As Variant, mDRange As Variant
  Set mDdict = CreateObject("Scripting.Dictionary")
 
  With Worksheets("mD")
  mDRange = .Range("A1:I" & .Cells(Rows.Count, 1).End(xlUp).Row)
  End With
  With Worksheets("mI")
  mIRange = .Range("A1:Q" & .Cells(Rows.Count, 1).End(xlUp).Row)
  For i = 1 To UBound(mDRange, 1)
    If Not mDdict.exists(mDRange(i, 1) & mDRange(i, 8)) Then
      mDdict.Add mDRange(i, 1) & mDRange(i, 8), mDRange(i, 9)
    End If
  Next
  For i = 1 To UBound(mIRange, 1)
    If mDdict.exists(mIRange(i, 1) & mIRange(i, 12)) Then
      mIRange(i, 17) = mDdict(mIRange(i, 1) & mIRange(i, 12))
    End If
  Next
  .Range("Q1").Resize(UBound(mIRange)) = WorksheetFunction.Index(mIRange, 0, 17)
  End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,215,071
Messages
6,122,964
Members
449,094
Latest member
Anshu121

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