+ Reply to Thread
Results 1 to 6 of 6

arrays in VBA

Hybrid View

  1. #1
    Registered User
    Join Date
    07-31-2007
    Posts
    35

    arrays in VBA

    Is there a simple way to insert a bunch of 1-D arrays into a 2-D array without cycling through every single cell? I want to just lump in entire rows or columns (1-D arrays) at a time and not cycle through the individual cells if I don't have to.

    Thanks

  2. #2
    Valued Forum Contributor mudraker's Avatar
    Join Date
    11-10-2003
    Location
    Melbourne, Australia
    Posts
    3,983
    The quickest easiest way to populate an array from a sheet is

    Dim vArr As Variant
    vArr = Range("a1:a10")
    change rows & columns to suit
    this gives a 1 dimension array

    If you need a 2 dimenstion array with the 2nd dimention blank have your data in column A & column B blank

    vArr = Range("a1:b10")
    Please Read Forum Rules Before Posting
    Wrap VBA code by selecting the code and clicking the # icon or Read This
    How To Cross Post politely

    Top Excel links for beginners to Experts

    If you are pleased with a member's answer then use the Scales icon to rate it
    If my reply has assisted or failed to assist you I welcome your Feedback.

  3. #3
    Forum Guru
    Join Date
    08-15-2004
    Location
    Tokyo, Japan
    MS-Off Ver
    2013 O.365
    Posts
    22,834
    Quote Originally Posted by mudraker
    The quickest easiest way to populate an array from a sheet is

    Dim vArr As Variant
    vArr = Range("a1:a10")
    change rows & columns to suit
    this gives a 1 dimension array
    No
    When you convert range value to vb array, it will be always 1 based 2D array, no exception.
    And if you want blank...
    Dim a As Variant
    a = Range("a1" Range("a" & Rows.Count).End(xlUp)).Value
    ReDim Preserve a(1 To UBound(a,1), 1 To UBound(a,2) + 1)
    will give you Col.A value & same length of blank col.

  4. #4
    Valued Forum Contributor mudraker's Avatar
    Join Date
    11-10-2003
    Location
    Melbourne, Australia
    Posts
    3,983
    jindon

    Thanks for pointing out my error that my code gives a 1 dimension array which is incorrect.


    This line of your code will cause incorrect
    a = Range("a1" Range("a" & Rows.Count).End(xlUp)).Value
    It should be
    a = Range("a1", Range("a" & Rows.Count).End(xlUp)).Value

  5. #5
    Forum Contributor VBA Noob's Avatar
    Join Date
    04-25-2006
    Location
    London, England
    MS-Off Ver
    xl03 & xl 07(Jan 09)
    Posts
    11,988
    Some links on arrays

    http://puremis.net/excel/code/053.shtml

    http://www.dailydoseofexcel.com/arch...nge-using-vba/

    http://www.exceltip.com/st/Array_var...Excel/509.html

    Variant array to hold two arrays. Step throught this sample subroutine with the immediate window open

    Sub Test() 
      Dim X As Long 
      Dim Arr1 As Long 
      Dim Arr2 As Long 
      Dim VarArray As Variant 
      '    Array function arrays are zero based 
      '    unless Option Base 1 is used. 
      Arr1 = 0 
      Arr2 = 1 
      '    We use VarArray to hold two elements, 
      '    each of which is an array. 
      VarArray = Array(Array("A", "B"), Array("C", "D", "E", "F")) 
      '    Note the syntax to address each array... a double pair of 
      '    parentheses... the first set address which array member of 
      '    VarArray we want, the second set addresses the element 
      '    of the member array we want. 
      Debug.Print "******** Arr1 member elements ********" 
      For X = LBound(VarArray(Arr1)) To UBound(VarArray(Arr1)) 
        Debug.Print VarArray(Arr1)(X) 
      Next 
      Debug.Print "******** Arr2 member elements ********" 
      For X = LBound(VarArray(Arr2)) To UBound(VarArray(Arr2)) 
        Debug.Print VarArray(Arr2)(X) 
      Next 
      Debug.Print "******** DONE ********" 
    End Sub



    VBA Noob
    Last edited by VBA Noob; 10-28-2007 at 12:19 PM.
    _________________________________________


    Credo Elvem ipsum etian vivere
    _________________________________________
    A message for cross posters

    Please remember to wrap code.

    Forum Rules

    Please add to your signature if you found this link helpful. Excel links !!!

  6. #6
    Forum Contributor
    Join Date
    11-11-2005
    Posts
    267

    Addendum to Jindon's comment

    To qualify Jindon's observation that "when you convert range value to vb array, it will be always 1 based 2D array, no exception", it must however be noted that when range transposition is involved, you can sort of convert range values to a 1D Array as the following codes illustrate.

    1. The simple transposition of one-column range:

    Sub TestForDimensionsOfVariantArray1()
    Dim v As Variant
    
    'populate A1:A5
    For i = 1 To 5
    Cells(i, 1).Value = Randbetween(1, 10)
    Next
    
    v = Range("a1:a5")
    v = Application.Transpose(Range("a1:a5"))
    MsgBox "Test for v dimensions"
    
    MsgBox "Test for v dimensions"
    MsgBox LBound(v, 1) 'ans=1
    MsgBox UBound(v, 1) 'ans=5
    MsgBox LBound(v, 2) 'ans="Subscript out 0f range error"
    MsgBox UBound(v, 2) 'ans="Subscript out 0f range error"
    'Conclusion: Variant array is 1-D
    'of size v(1 To 5)
    End Sub
    2. The double transposition scenarios

    Sub TestForDimensionsOfVariantArray2()
    Dim v As Variant, v2 As Variant, v3 As Variant
    
    
    'populate A1:E5
    For i = 1 To 5
    Cells(1, i) = Randbetween(2, 10)
    Next
    
    'CASE #1
    v = Range("a1:e1")
    MsgBox "Test for v dimensions"
    MsgBox LBound(v, 1) 'ans=1
    MsgBox UBound(v, 1) 'ans=1
    MsgBox LBound(v, 2) 'ans=1
    MsgBox UBound(v, 2) 'ans=5
    'conclusion: Variant array is 2-D
    'of size v(1 To 1, 1 To 5)
    
    
    'CASE #2
    v2 = Application.Transpose(Range("a1:e1"))
    MsgBox "Test for v2 dimensions"
    MsgBox LBound(v2, 1) 'ans=1
    MsgBox UBound(v2, 1) 'ans=5
    MsgBox LBound(v2, 2) 'ans=1
    MsgBox UBound(v2, 2) 'ans=1
    'Conclusion: Variant array is 2-D
    'of size v(1 To 5, 1 To 1)
    
    'CASE #3
    v3 = Application.Transpose(Application.Transpose(Range("a1:e1")))
    MsgBox "Test for v3 dimensions"
    MsgBox LBound(v3, 1) 'ans=1
    MsgBox UBound(v3, 1) 'ans=5
    MsgBox LBound(v3, 2) 'ans="Subscript out 0f range error"
    MsgBox UBound(v3, 2) 'ans="Subscript out 0f range error"
    'Conclusion: Variant array is 1-D'
    of size v(1 To 5)
    
    End Sub
    There is no doubt that it is this property of Array dimension changing by transposition from one-column range (2D) to putatively a one-row range (ID) that gives the illusion that "horizontal single row range" gives rise to a 1-D Array.

    Outside the context of transposition, Jindon is perfectly right. I was only a bit uneasy about the rider "no exception". Again, as he pointed out, Variant arrays are by definition typecast to Base1.
    Last edited by Myles; 10-31-2007 at 12:45 AM.
    HTH
    Myles

    ...constantly looking for the smoother pebble while the whole ocean of truth lies before me.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1