Sub EasySol()
Dim LR As Long
LR = ActiveSheet.Cells(Rows.Count, "A").End(xlUp).Row
Range("A1:A" & LR).AdvancedFilter Action:=xlFilterCopy, CopyToRange:=Range("J1"), Unique:=True
End Sub
Sub test()
Dim a, e, j(), n As Long
a = Range("a1", Range("a" & Rows.Count).End(xlUp)).Value
Columns("j").ClearContents
If Not IsArray(a) Then
Range("j1").Value = a: Exit Sub
End If
ReDim j(1 To UBound(a, 1), 1 To 1)
With CreateObject("Scripting.Dictionary")
.CompareMode = vbTextCompare
For Each e In a
If Not IsEmpty(e) And Not .exists(e) Then
n = n + 1: j(n, 1) = e
.Add e, Nothing
End If
Next
End With
Range("j1").Resize(n).Value = j
End Sub