Output rows in array

cortexnotion

Board Regular
Joined
Jan 22, 2020
Messages
150
Office Version
  1. 2013
Platform
  1. Windows
Hi All

Could you help me finish the below? I am putting my very large data range into an array and looking to find matching rows and copy to the next sheet. Is it better to put the results into an output array and output at once or individually?

Any help appreciated.

VBA Code:
Sub vbamatch()

Dim InAry As Variant, LR1 As Long, LW1 As Long, a As Long

LR1 = ThisWorkbook.Sheets("Sheet1").Range("A" & Rows.Count).End(xlUp).Row
InAry = ThisWorkbook.Sheets("Sheet1").Range("A2:O" & LR1).Value
ColorAry = Array("Red","Blue","Yellow","Green","Brown","Black")
LW1 = Application.Evaluate("INT((TODAY()-1)/7)*7+1")

For a = 1 To LR1
        If InAry(a, 1) = LW1 & InAry(a, 5) = ColorAry(0) Then 'copy matching row to Sheet2 Range A2:O2
        If InAry(a, 1) = LW1 & InAry(a, 5) = ColorAry(1) Then 'copy matching row to Sheet2 Range A3:O3
        If InAry(a, 1) = LW1 & InAry(a, 5) = ColorAry(2) Then 'copy matching row to Sheet2 Range A4:O4
        If InAry(a, 1) = LW1 & InAry(a, 5) = ColorAry(3) Then 'copy matching row to Sheet2 Range A5:O5
        If InAry(a, 1) = LW1 & InAry(a, 5) = ColorAry(4) Then 'copy matching row to Sheet2 Range A6:O6
        If InAry(a, 1) = LW1 & InAry(a, 5) = ColorAry(5) Then 'copy matching row to Sheet2 Range A7:O7
Next a
End Sub
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
Putting the data into another array & writting to the sheet once only, will be faster.
 
Upvote 0
Try something like
VBA Code:
InAry = ThisWorkbook.Sheets("Sheet1").Range("A2:O" & LR1).Value
ReDim OutAry(1 To UBound(InAry), 1 To 15)
colorary = "|Red|Blue|Yellow|Green|Brown|Black|"
LW1 = Application.Evaluate("INT((TODAY()-1)/7)*7+1")

For a = 1 To UBound(InAry)
   If InAry(a, 1) = LW1 Then
      If InStr(1, colorary, "|" & InAry(a, 5) & "|", vbTextCompare) > 0 Then
        nr = nr + 1
        For c = 1 To UBound(InAry, 2)
            OutAry(nr, c) = InAry(a, c)
         Next c
      End If
   End If
Next a
 
Upvote 0
Solution
Thank you @Fluff, nifty putting the array into one string. Can I ask advice on a variation, if I need to compare dates would you follow the same logic to put the dates in a string and compare?

I tried to modify your code to the below but it wipes the whole sheet...

VBA Code:
Sub dates()

Dim InAry As Variant, OutAry As Variant, WkAry As String, LR1 As Long, a As Long, c As Long, nr As Long

LR1 = ThisWorkbook.Sheets("FigWork").Range("B" & Rows.Count).End(xlUp).Row
InAry = ThisWorkbook.Sheets("FigWork").Range("A10:O" & LR1).Value
ReDim OutAry(1 To UBound(InAry), 1 To 15)

LW1 = Application.Evaluate("INT((TODAY()-1)/7)*7+1")

WkAry = "|" & LW1 & "|" & LW1 - 7 & "|" & LW1 - 14 & "|" & LW1 - 21 & "|" & LW1 - 28 & "|" & LW1 - 35 & "|"

For a = 1 To UBound(InAry)
   If InStr(1, WkAry, "|" & InAry(a, 5) & "|", vbTextCompare) > 0 Then
        nr = nr + 1
        For c = 1 To UBound(InAry, 2)
            OutAry(nr, c) = InAry(a, c)
         Next c
      End If
Next a

ThisWorkbook.Sheets("FigWork").Range("A2:O2").Resize(UBound(OutAry)).Value = OutAry

End Sub
 
Upvote 0
You could try
VBA Code:
If InStr(1, WkAry, "|" & CLng(InAry(a, 5)) & "|", vbTextCompare) > 0 Then
 
Upvote 0
Thanks @Fluff

With either example when I output the array I get the right rows then hundreds of empty rows that overwrite existing rows lower in the sheet.

Is there something wrong with the size/output of the OutAry below?

VBA Code:
ThisWorkbook.Sheets("FigWork").Range("A2:AB2").Resize(UBound(OutAry)).Value = OutAry

Thanks!
 
Upvote 0
Use
VBA Code:
ThisWorkbook.Sheets("FigWork").Range("A2:AB2").Resize(nr).Value = OutAry
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,251
Members
448,556
Latest member
peterhess2002

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