Dynamic array not working

niall91

New Member
Joined
Jul 21, 2020
Messages
45
Office Version
  1. 2019
Platform
  1. Windows
Hi guys

Im using a dynamic array to scan through a range and pull out information but the array dosnt seem to be working as an array because i only gets the last value it finds.

VBA Code:
Sub ExportToInvoice2()
Dim wRange As Range
Dim cell As Range
Dim myArray() As Variant
Dim i As Long
Sheets("Frame Variables").Select
Set wRange = Range("AQ10:AQ416")

For Each cell In wRange
    ReDim Preserve myArray(i)
    x = cell
    x = Mid(cell, 1, 1)
    If x = "U" Then
        myArray(i) = cell.Value
    MsgBox myArray(i)
    End If
 
Next cell
   
For a = LBound(myArray) To UBound(myArray)
    'Debug.Print myArray
    lr = ThisWorkbook.Sheets("sheet1").Cells(Rows.Count, 1).End(xlUp).Row
    Sheets("Sheet1").Cells(lr + 1, 1) = myArray
Next a


End Sub
 
Last edited by a moderator:

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
You are not incrementing the value of i, how about
VBA Code:
Sub ExportToInvoice2()
   Dim wRange As Range
   Dim cell As Range
   Dim myArray() As Variant
   Dim i As Long
   Sheets("Frame Variables").Select
   Set wRange = Range("AQ10:AQ416")
  
   ReDim myArray(1 To wRange.Count, 1 To 1)
   For Each cell In wRange
      If Left(cell, 1) = "U" Then
         i = i + 1
         myArray(i, 1) = cell.Value
         Debug.Print myArray(i, 1)
      End If
   Next cell
    
   'Debug.Print myArray
   lr = ThisWorkbook.Sheets("sheet1").Cells(Rows.Count, 1).End(xlUp).Row
   Sheets("Sheet1").Cells(lr + 1, 1).Resize(i).Value = myArray


End Sub
 
Last edited:
Upvote 0
When posting vba code, please use code tags - more information in my signature block below. I have fixed your post for you this time.

I also suggest that you update your Account details - also see my signature block below.

In case you are interested, here is a different approach that doesn't require looping through the cells individually.
I have assumed that your range does not contain any "|" or "#" characters but they could be changed to something else if required.

VBA Code:
Sub ExportToInvoice3()
  Dim a As Variant
  
  With Sheets("Frame Variables")
    a = Filter(Split("#" & Join(Application.Transpose(.Range("AQ10", .Range("AQ" & Rows.Count).End(xlUp)).Value), "|#"), "|"), "#U", True, 0)
  End With
  Sheets("Sheet1").Cells(Rows.Count, 1).End(xlUp).Offset(1).Resize(UBound(a) + 1).Value = Application.Transpose(Split(Mid(Join(a), 2), " #"))
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,538
Messages
6,114,220
Members
448,554
Latest member
Gleisner2

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