Removing Elements from Collection

smpatty08

Board Regular
Joined
May 16, 2014
Messages
155
I am trying to remove empty elements from a Collection. Here is the code I have so far.

Code:
Sub T()
Dim i As Integer
Dim Altered As New Collection
 
Altered.Add Range(Cells(12, 2), Cells(19, 12)).FormulaR1C1
 
For i = 1 To Altered.Count
    If Altered.Item(i) = "" Then
        Altered.Remove i
    End If
Next i
 
End Sub

From the Locals window here is what Altered looks like:
Altered
Item 1(1)
Item 1(2)
Item 1(3)
Item 1(4)​
Item 1(4,1) ""
Item 1(4,2) ""
Item 1(4,3) ""
Item 1(4,4) ""
Item 1(4,5) ""
Item 1(4,6) ""
Item 1(4,7) ""
Item 1(4,8) ""
Item 1(4,9) ""
Item 1(4,10) ""
Item 1(4,11) ""​
Item 1(5)
Item 1(6)
Item 1(7)
Item 1(8)
Item 1(9)
Item 1(10)
Item 1(11)​

I would like to remove all elements of Item 1(4) so I can paste the collection back into Range(Cells(12, 2), Cells(19, 12))

My Table looks like this
Start:
ABCDEFGHIJKL
1211111111111
1311111111111
1411111111111
15
1611111111111
1711111111111
1811111111111
1911111111111

<tbody>
</tbody>

I want it to look like this when done:
ABCDEFGHIJKL
1211111111111
1311111111111
1411111111111
1511111111111
1611111111111
1711111111111
1811111111111
19

<tbody>
</tbody>

Any help is appreciated!
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
I would not use a collection for that purpose. And your goal is not clear.
Do you want to remove each cell that is empty
or each row where every cell in the row is empty
or each row where any of the cells in that row are empty.

One quick approach might be
Code:
Range(Cells(12, 2), Cells(19, 12)).SpecialCells(xlCellTypeBlanks).Delete shift:=xlUp
 
Upvote 0
I would not use a collection for that purpose. And your goal is not clear.
Do you want to remove each cell that is empty
or each row where every cell in the row is empty
or each row where any of the cells in that row are empty.

One quick approach might be
Code:
Range(Cells(12, 2), Cells(19, 12)).SpecialCells(xlCellTypeBlanks).Delete shift:=xlUp

I would like to arrange the rows that contain data to make them contiguous and put all the blanks at the bottom. I would rather not delete the row completely because it would mess up some formatting elsewhere is the worksheet.
 
Upvote 0
Code:
Dim inArray as Variant, outArray() as String
Dim i as Long, j as Long, k as Long, m as Long

inArray = Range(Cells(12, 2), Cells(19, 12)).FormulaR1C1

ReDim outArray(1 to UBound(inArray,1), 1 to UBound(inArray, 2))

k = 1: m = 1
For i = 1 to UBound(inArray,1)
    For j = 1 to UBound(inArray, 2)
        If inArray(i, j) <> "" then
            outArray(k, m) = inArray(i, j)
            m = m+1: If UBound(outArray,2) < m Then k = k+1: m=1
        End If
    Next j
Next i

Range(Cells(12, 2), Cells(19, 12)).FormulaR1C1 = outArray
 
Upvote 0
Code:
Dim inArray as Variant, outArray() as String
Dim i as Long, j as Long, k as Long, m as Long

inArray = Range(Cells(12, 2), Cells(19, 12)).FormulaR1C1

ReDim outArray(1 to UBound(inArray,1), 1 to UBound(inArray, 2))

k = 1: m = 1
For i = 1 to UBound(inArray,1)
    For j = 1 to UBound(inArray, 2)
        If inArray(i, j) <> "" then
            outArray(k, m) = inArray(i, j)
            m = m+1: If UBound(outArray,2) < m Then k = k+1: m=1
        End If
    Next j
Next i

Range(Cells(12, 2), Cells(19, 12)).FormulaR1C1 = outArray

After I updated
Code:
outArray() as String
To
Code:
outArray as Variant
It worked perfectly
This is exactly what I needed! Thank You!
 
Upvote 0

Forum statistics

Threads
1,214,944
Messages
6,122,387
Members
449,080
Latest member
Armadillos

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