Formula Help Please

How_Do_I

Well-known Member
Joined
Oct 23, 2009
Messages
1,843
Office Version
  1. 2010
Platform
  1. Windows
In Column B there can be a maximum of 12 unique numbers.
<?xml:namespace prefix = o ns = "urn:schemas-microsoft-com:office:office" /><o:p> </o:p>
D1 is a count of how many numbers in Column B
<o:p> </o:p>
In F1 I need a formula that will work regardless of how many of my 12 numbers are in Column B.
<o:p> </o:p>
So if I place 40 in B3, I would want F1 to = 23, 32, 40
<o:p> </o:p>
Can this be done please?

Excel Workbook
ABCDEF
1123223, 32
2232
33
44
55
66
77
88
99
1010
1111
1212
Sheet1
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
As an alternative, this one has been around for a while

Rich (BB code):
Function AConcat(a As Variant, Optional Sep As String = "") As String
' Harlan Grove, Mar 2002

    Dim Y As Variant

    If TypeOf a Is Range Then
    
        For Each Y In a.Cells
            AConcat = AConcat & Y.Value & Sep
        Next Y
    
    ElseIf IsArray(a) Then
    
        For Each Y In a
            AConcat = AConcat & Y & Sep
        Next Y
        
    Else
    
        AConcat = AConcat & a & Sep
    
    End If        AConcat = Left(AConcat, Len(AConcat) - Len(Sep))    End Function

I've tried mrKowz version on a few things and it works well, but appears to fail on conditional arrays.

{concatrange(if(.......))}
 
Upvote 0
If you need a conditional concatenate, ZVI programmed this little beauty for me when I was inquiring about how to pass conditions through UDFs:

Code:
' ZVI:2011-03-09 [URL]http://www.mrexcel.com/forum/showthread.php?t=534231[/URL]
' Function to return concatenated values of RngToConcat for which Condition happens
' Optional Delim argument (comma) is the delimiter of the resulting list
' Note1:   It's faster if performed as array formula via Ctrl-Shift-Enter
' Note2:   Decimal separator of numbers is the dot char for all localizations
' Example: =ConcatIf(A1:A10, (B1:B10>1)*(C1:C10<10), CHAR(10))
Function ConcatIf(RngToConcat As Range, Condition, Optional Delim$ = ",") As String
  
  ' Variables are reserved for:
  ' a - for array/value of RngToConcat, processing of array is faster than of range
  ' b - for array/value of Condition, used also for parsing of Condition part from the caller formula
  ' r - row counter, rs - rows count
  ' c - column counter, cs - columns count
  ' s - concatenated string, used also as temporary variable
  ' x - temporary variable
  ' vt - vartype of x-variable
  ' In Dim the suffix "&" is equal to "As Long", "$" =  "As String"
  Dim vt As VbVarType, A, B, i&, r&, rs&, c&, cs&, s$, x
  
  ' Copy range value to variable, processing of VBA array is much faster than processing of range
  A = RngToConcat.Value
  
  ' If only 1 cell is on the RngToConcat, then a-variable is not array, else it's array
  If Not IsArray(A) Then
    ' There is only single cell in RngToConcat - process it and exit
    If Condition Then ConcatIf = A: Exit Function
  End If
  
  ' Copy Condition to b-variable
  B = Condition
  
  ' If formula was entered as array formyla by CSE, then b-variable is array, else it's not array
  If Not IsArray(B) Then
    ' Ctrl-Shift-Enter was not performed - do evaluation of Condition formula(s)
    
    With Application.ThisCell
      ' Application.ThisCell.Formula gives the formula of the caller cell
      
      ' Temporarily split that formula with comma delimiter into zero based b() array
      B = Split(.Formula, ",")
      
      ' b() now is zero based array, b(1) consists Conditional equation
      ' It is assumed that comma is not used in Conditional equation, if does than more strong parsing is required
      s = B(1)
      
      ' If optional Delim was not passed into function then delete right round bracket
      If UBound(B) = 1 Then s = Left$(s, Len(s) - 1)
      
      ' Evaluate Condition in the sheet with caller cell
      ' Application.ThisCell.Parent is reference to that sheet
      B = .Parent.Evaluate(s)
      
      ' Clean s for later usage
      s = ""
      
    End With
  
  End If
  
  ' Calc rows count in b()
  rs = UBound(B, 1)
  
  ' Calc columns count in b()
  cs = UBound(B, 2)
  
  ' Loop through b() array,
  ' if not Error/False/Empty/Zero condition found
  ' then get value from a() at the same row & column for concatenation
  For r = 1 To rs
    For c = 1 To cs
      x = B(r, c)
      If VarType(x) <> vbError Then
        ' value of b(r, c) is not error - process it
        If x Then
          ' value of b(r, c) is not False/Zero/Empty - get value from a() at the same row & column
          x = A(r, c)
          vt = VarType(x)
          If vt <> vbError Then
            ' value of a(r, c) is not error - process it
            If Len(x) Then
              ' value of a(r, c) is not empty - provide dot char as the decimal separator for all localizations
              If IsNumeric(x) And vt <> vbString Then x = Trim$(str(x))
              ' Concatenate the result in temporary s-variable
              s = s & x & Delim
            End If
          End If
        End If
      End If
    Next
  Next
  
  ' Set result
  i = Len(s)
  
  ' Delete the last comma in s
  If i Then ConcatIf = Left$(s, i - Len(Delim))
  
End Function
 
Upvote 0
Where is these macros stored and can they be made available as a UDF so they're available in all workbooks? where is the code pasted and saved?

would like to give them a try
 
Upvote 0
Hello again

There's a problem with formatting of the code that Jason, posted, the last three lines have been concatenated into one. :biggrin:

It should be like below.

Code:
Function AConcat(a As Variant, Optional Sep As String = "") As String
' Harlan Grove, Mar 2002

    Dim Y As Variant

    If TypeOf a Is Range Then
    
        For Each Y In a.Cells
            AConcat = AConcat & Y.Value & Sep
        Next Y
    
    ElseIf IsArray(a) Then
    
        For Each Y In a
            AConcat = AConcat & Y & Sep
        Next Y
        
    Else
    
        AConcat = AConcat & a & Sep
    
    End If
    
        AConcat = Left(AConcat, Len(AConcat) - Len(Sep))
        
    End Function
 
Upvote 0
Thanks meldoc, can you confirm where I put this code? is it into a module then save that workbook as an Excel Addin? Whats the syntax for using thereafter
 
Upvote 0
Good catch meldoc, I didn't see that the last lines had concatenated when I submitted the post. Might have been a formatting bug cos I only did a quick copy / paste and the original was fine.
 
Upvote 0

Forum statistics

Threads
1,224,505
Messages
6,179,151
Members
452,891
Latest member
JUSTOUTOFMYREACH

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