MoreFunc Array.Join Alternative

alexcn

Board Regular
Joined
Apr 8, 2003
Messages
64
Hey everyone,

Do any of you know an alternative to the Array.Join function (either formula or UDF) in Excel as I have traced the source of my crashing workbooks to this function which in all instances concatenate two named ranges of text data, and then produce a list of unique values using the UNIQUEVALUES function.

Any help would be greatly appreciated,

Regards,

Alex
 

alexcn

Board Regular
Joined
Apr 8, 2003
Messages
64
Even if I remove the named ranges, and just try the following formula:

{=TRIM(UNIQUEVALUES(ARRAY.JOIN(" "," "),1)}

It still crashes, so there seems to be a serious problem with ARRAY.JOIN. Has anyone seen this behaviour before?

Thanks,

Hey everyone,

Do any of you know an alternative to the Array.Join function (either formula or UDF) in Excel as I have traced the source of my crashing workbooks to this function which in all instances concatenate two named ranges of text data, and then produce a list of unique values using the UNIQUEVALUES function.

Any help would be greatly appreciated,

Regards,

Alex
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
Hi Alex

One issue could be the length of the returned string - it won't work if it is more than 255 characters.
 

alexcn

Board Regular
Joined
Apr 8, 2003
Messages
64
Dear Richard,

Many thanks for your response, yes I agree with your thoughts however I have other array formulae that have contents greated than 255 characters (or is this just something native to the ARRAY.JOIN function that you know of?) This also doesnt get around WHY the ARRAY.JOIN on two single space strings fails either (i.e. " ", joined with the same)

Regards,

Alex
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
MoreFunc functions won't return strings greater than 255 characters (i should have made that clear). I am afraid i don't know why ARRAY.JOIN may fail on shorter strings.
 

alexcn

Board Regular
Joined
Apr 8, 2003
Messages
64
Hmmm that's strange then, as the component values of the formula havent changed but suddenly the function stops working, also I suspect since it crashes on single character strings then the 255 character length is not, in this instance, the cause of my error.

Do you know of any way to achieve the same result and avoid using the ARRAY.JOIN function?
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
Probably a UDF - what does the ARRAY.JOIN function actually do?
 

alexcn

Board Regular
Joined
Apr 8, 2003
Messages
64
Basically given mutliple arrays of values:

ABC and 123
DEF 456
ABC 123
DEF 456

It will return:

ABC
DEF
ABC
DEF
123
456
123
456

The function help is as follows:

Joins various items (ranges, numbers, strings...) in a vertical array and returns this array. ARRAY.JOIN allows to pass union of ranges to several functions which don't support them.

SYNTAX :
=ARRAY.JOIN(Item 1,Item 2,...,Item 29)

- Item 1 to Item 29 : items to join.

REMARKS :
The items can have any type supported by Excel : numbers, strings, booleans, ranges, unions of ranges, named ranges, constant arrays and so on.

RETURNED VALUE :
ARRAY.JOIN joins the items in an one-column array. The total number of items is limited to 65535.
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
Try using this as a UDF in place of Array.Join:

Code:
Function ArrayJoin(ParamArray vArgs() As Variant) As Variant
Dim vArg As Variant
Dim vArray As Variant
Dim i As Long
Dim cnt As Long
cnt = 0
For i = LBound(vArgs) To UBound(vArgs)
    Select Case TypeName(vArgs(i))
        Case "Range"
            cnt = cnt + vArgs(i).Count
        Case Else
            If InStr(1, TypeName(vArgs(i)), "(") > 0 Then
                cnt = cnt + UBound(vArgs(i)) - LBound(vArgs(i)) + 1
            Else
                cnt = cnt + 1
            End If
    End Select
Next i
ReDim vArray(1 To cnt, 1 To 1)
cnt = 1
For i = LBound(vArgs) To UBound(vArgs)
    Select Case TypeName(vArgs(i))
        Case "Range"
            For Each vArg In vArgs(i)
                vArray(cnt, 1) = vArg
                cnt = cnt + 1
            Next vArg
        Case Else
            If InStr(1, TypeName(vArgs(i)), "(") > 0 Then
                For Each vArg In vArgs(i)
                    vArray(cnt, 1) = vArg
                    cnt = cnt + 1
                Next vArg
            Else
                vArray(cnt, 1) = vArgs(i)
                cnt = cnt + 1
            End If
    End Select
Next i
ArrayJoin = vArray
        
End Function
Note that it is very lightly tested and may contain many errors/bugs causing it not to work. You would re-write your formula to look like:

={=TRIM(UNIQUEVALUES(ARRAYJOIN(" "," "),1)}
 

alexcn

Board Regular
Joined
Apr 8, 2003
Messages
64
Dear Richard,

WOW that works perfectly, thanks so much for taking the time to reply and offer this solution.

Regards,

Alex
 

Forum statistics

Threads
1,081,518
Messages
5,359,236
Members
400,523
Latest member
ExcelNewbie98

Some videos you may like

This Week's Hot Topics

  • VBA (Userform)
    Hi All, I just would like to know why my code isn't working. Here is my VBA code: [CODE=vba]Private Sub OKButton_Click() Dim i As Integer...
  • List box that changes fill color
    Hello, I have gone through so many pages trying to figure this out. I have a 2020 calendar that depending on the day needs to have a certain...
  • Remove duplicates and retain one. Cross-linked cases
    Hi all I ran out of google keywords to use and still couldn't find a reference how to achieve the results of a single count. It would be great if...
  • VBA Copy and Paste With Duplicates
    Hello All, I'm in need of some input. My VBA skills are sub-par at best. I've assembled this code from basic research and it works but is...
  • Macro
    is it possible for a macro to run if the active cell value is different to the value above it
  • IF DATE and TIME
    I currently use this to check if date has passed but i also need to set a time on it too. Is it possible? [CODE=vba]=IF(B:B>TODAY(),"Not...
Top