User Defined "Union" function to ignore "Nothing" entries

smeador

New Member
Joined
Nov 30, 2014
Messages
12
Hello,

I have a user defined function as seen below that allows me to combine two non-adjacent columns into a contiguous array.

Code:
Function MakeContig(ParamArray av() As Variant) As Variant
    Dim avOut() As Variant
    Dim i       As Long
    Dim j       As Long


    ReDim avOut(1 To av(0).Count, 0 To UBound(av))
    For j = 0 To UBound(av)
        For i = 1 To av(j).Rows.Count
            avOut(i, j) = av(j)(i)
        Next i
    Next j
    MakeContig = avOut
End Function

So, if I type "=makecontig(A1:A5,E1:E5)" into a cell, a single array is formed consisting of the two columns included in the formula. I would like to be able to edit this function so that it ignores a non-array entry.

For example, if i type "=makecontig(A1:A5,E1:E5, , )" or =makecontig(A1:A5,E1:E5,Nothing)" I would like it to ignore the error or blank parameter and only create a contiguous array for A1:A5 and E1:E5.

I imagine I need to include an If/Then statement somewhere in UDF but I cannot seem to figure out how to execute it properly.

Any help would be appreciated!
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Try this code. It only processes RANGE arguments, all others are ignored.
While I was at it I made it so the ranges can be of different sizes. The number of rows in the output array equals the number of cells in the largest range. Excess rows in the smaller ranges are zero filled.
Code:
Option Explicit

Function MakeContig(ParamArray av() As Variant) As Variant
    Dim avOut() As Variant
    Dim i       As Long
    Dim j       As Long
    Dim notEcnt As Long
    Dim maxRows As Long
    Dim outCol  As Long
    
    notEcnt = -1
    For i = 0 To UBound(av())
        If Not IsError(av(i)) Then
          If TypeOf av(i) Is Range Then
            notEcnt = notEcnt + 1
            If av(i).Rows.Count > maxRows Then _
                maxRows = av(i).Rows.Count
          End If
        End If
    Next i
    
    ReDim avOut(1 To maxRows, 0 To notEcnt)
    
    outCol = -1
    For j = 0 To UBound(av())
        If Not IsError(av(j)) Then
          If TypeOf av(j) Is Range Then
            outCol = outCol + 1
            For i = 1 To maxRows
                avOut(i, outCol) = av(j)(i)
            Next i
          End If
        End If
    Next j
    MakeContig = avOut
End Function
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,109
Members
452,302
Latest member
TaMere

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