How to Union Range and output into an array?

ke9c

Board Regular
Joined
Jul 27, 2010
Messages
75
I have a table range contains data from ColA to colG, i want to select some col inside the range and union them together to put into a array, i use below codes, but it seems vArray turns out to be contain only one col (ColA) data only, how can i change the code so that it will contain col 1, 4, 6, 7? Thanks

Code:
Sub test()
Call EquityCSV(Range("A4:G80"))
End Sub
 
Sub EquityCSV(rEquityRange As Range)
Dim rRange As Range
Set rRange = Application.Union(rEquityRange.Columns(1), rEquityRange.Columns(4), _
rEquityRange.Columns(6), rEquityRange.Columns(7))
rRange.Select
Dim vArray As Variant
vArray = rRange.Value
End Sub
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
If the range is non-contiguous then you need to loop thru each area within the range and write it to the array. One way you might do this is to have a holding (jagged) array the elements of which will each contain one area's worth of data (eg one column in your case):

Code:
Sub test()
Dim vHolding As Variant   'holding array

Dim rng As Range

Dim i As Long  'loop counter

Set rng = Range("C14:C30,F20:F40,K16:K43,Q40:Q42")

ReDim vHolding(1 To rng.Areas.Count)  'resize holding array to number of contiguos ranges in rng

'loop thru rng.Areas:
For i = 1 To rng.Areas.Count
    vHolding(i) = rng.Areas(i).Value   'will create an array as element i in vholding (unless single cell range)
Next i

'to access individual cells, you need to use following syntax:

MsgBox vHolding(3)(3, 1)

'to write back to ranges, need to do each element at a time:

Worksheets.Add
Range("A1").Resize(UBound(vHolding(3), 1), UBound(vHolding(3), 2)).Value = vHolding(3)

End Sub
 
Upvote 0
Hi

In this case, since you have a table and want to address the intersection of rows and columns, you can also address them directly using Index(), like:

Code:
Sub test()
Dim vArray As Variant
 
vArray = EquityCSV(Range("A4:G10"))
' do something with vArray
End Sub
 
Function EquityCSV(rEquityRange As Range)
Dim vRows As Variant
 
vRows = Evaluate("row(" & rEquityRange.Address & ")-" & rEquityRange.Row & "+1")
EquityCSV = Application.Index(rEquityRange, vRows, Array(1, 4, 6, 7))
End Function
 
Upvote 0

Forum statistics

Threads
1,213,557
Messages
6,114,291
Members
448,564
Latest member
ED38

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