Counting the repeating values and displaying with alphanumeric symbols

Usercode

Board Regular
Joined
Aug 18, 2017
Messages
107
Office Version
  1. 2016
Platform
  1. Windows
Hello,

I am not sure if this can be done with a formula, but if it is, I would appreciate the help.

I have a set of data some of which can be repeated several times in the same row. And if the values are repeated, I'd like them to be displayed with alphanumeric symbols. For example, If data is (1,1,1,3,3,4,5), then the output should be 32R. (three 1s, two 3s). Since 4,5 and are not repeated, they are excluded. if data is (1,2,2,3,3,4,5), then the output should be 22R (two 2s and two 3s).

I have attached an example worksheet. Thanks!

https://1drv.ms/x/s!AoGkZUHlKui9gSEHkSskV6ynfmAJ
 
Last edited:
ACONCAT >>>

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

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Thanks again for your time and effort, Aladin. it's perfect.
 
Upvote 0
Instead of creating a function to duplicate TEXTJOIN in your version of Excel, why not just write a function to produce the result you want directly. The following UDF (user defined function) takes one argument... the range containing your sorted data.
Code:
Function RepeatCount(Rng As Range) As String
  Dim Cell As Range, Tmp As Variant
  With CreateObject("Scripting.Dictionary")
    For Each Cell In Rng
      .Item(CStr(Cell.Value)) = .Item(CStr(Cell.Value)) + 1
    Next
    RepeatCount = Join(Filter(.Items, 1, False), "") & [B][COLOR="#FF0000"]"R"[/COLOR][/B]
  End With
End Function
So to use this function, assuming your data was in the cells of the range A1:F1, you would simply use this formula...

=RepeatCount(A1:F1)

Note: My code affixes an "R" to the end of the repeat numbers because that is what you used in your original message; however, although Aladin started by using an "R" also, I see he is now using a "c". I am not sure why this changed, but if it is correct, then change the red highlighted "R" above to "c".
 
Last edited:
Upvote 0
@Rick

for 1-2-3-4-5-6-7 result must be "" and your UDF return R then

for all cells without number result is 7 R and should be ""

can you fixit?
 
Last edited:
Upvote 0
Ingolf, if I understood you correctly, you can remove the "R" from the code. and it will only give the result you want.

Code:
[COLOR=#333333]Function RepeatCount(Rng As Range) As String[/COLOR]  Dim Cell As Range, Tmp As Variant
  With CreateObject("Scripting.Dictionary")
    For Each Cell In Rng
      .Item(CStr(Cell.Value)) = .Item(CStr(Cell.Value)) + 1
    Next
    RepeatCount = Join(Filter(.Items, 1, False), "")
  End With [COLOR=#333333]End Function[/COLOR]
 
Upvote 0
@Rick

for 1-2-3-4-5-6-7 result must be "" and your UDF return R then

for all cells without number result is 7 R and should be ""

can you fixit?

also for:

3-3-3-3-3-""-"" result is 52R and should be 5R I think
 
Last edited:
Upvote 0
Ingolf, if I understood you correctly, you can remove the "R" from the code. and it will only give the result you want.

No. I don't want to just remove R

[TABLE="width: 407"]
<colgroup><col width="41" style="width: 31pt; mso-width-source: userset; mso-width-alt: 1499;" span="6"> <col width="64" style="width: 48pt;" span="3"> <col width="102" style="width: 77pt; mso-width-source: userset; mso-width-alt: 3730;"> <tbody>[TR]
[TD="class: xl67, width: 310, bgcolor: #C5D9F1, colspan: 7"]Data[/TD]
[TD="width: 64, bgcolor: transparent"][/TD]
[TD="class: xl66, width: 64, bgcolor: #C5D9F1"]Output[/TD]
[TD="width: 102, bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="class: xl65, bgcolor: transparent"]1[/TD]
[TD="class: xl65, bgcolor: transparent"]1[/TD]
[TD="class: xl65, bgcolor: transparent"]2[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]4[/TD]
[TD="class: xl65, bgcolor: transparent"]5[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"]22R[/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="class: xl65, bgcolor: transparent"]2[/TD]
[TD="class: xl65, bgcolor: transparent"]2[/TD]
[TD="class: xl65, bgcolor: transparent"]2[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]4[/TD]
[TD="class: xl65, bgcolor: transparent"]5[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"]32R[/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="class: xl65, bgcolor: transparent"]1[/TD]
[TD="class: xl65, bgcolor: transparent"]1[/TD]
[TD="class: xl65, bgcolor: transparent"]1[/TD]
[TD="class: xl65, bgcolor: transparent"]1[/TD]
[TD="class: xl65, bgcolor: transparent"]2[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]4[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"]4R[/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="class: xl65, bgcolor: transparent"]1[/TD]
[TD="class: xl65, bgcolor: transparent"]1[/TD]
[TD="class: xl65, bgcolor: transparent"]1[/TD]
[TD="class: xl65, bgcolor: transparent"]2[/TD]
[TD="class: xl65, bgcolor: transparent"]2[/TD]
[TD="class: xl65, bgcolor: transparent"]2[/TD]
[TD="class: xl65, bgcolor: transparent"]5[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"]33R[/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="class: xl65, bgcolor: transparent"]1[/TD]
[TD="class: xl65, bgcolor: transparent"]2[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]4[/TD]
[TD="class: xl65, bgcolor: transparent"]5[/TD]
[TD="class: xl65, bgcolor: transparent"]6[/TD]
[TD="class: xl65, bgcolor: transparent"]7[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="class: xl68, bgcolor: transparent"]R[/TD]
[TD="bgcolor: transparent"]Should be ""[/TD]
[/TR]
[TR]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="class: xl68, bgcolor: transparent"]52R[/TD]
[TD="bgcolor: transparent"]Should be 5R[/TD]
[/TR]
[TR]
[TD="class: xl65, bgcolor: transparent"][/TD]
[TD="class: xl65, bgcolor: transparent"][/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="class: xl65, bgcolor: transparent"]3[/TD]
[TD="bgcolor: transparent"][/TD]
[TD="class: xl68, bgcolor: transparent"]25R[/TD]
[TD="bgcolor: transparent"]Should be 5R[/TD]
[/TR]
</tbody>[/TABLE]
 
Last edited:
Upvote 0
@Rick

for 1-2-3-4-5-6-7 result must be "" and your UDF return R then

for all cells without number result is 7 R and should be ""

can you fixit?
Here is the fix...
Code:
[table="width: 500"]
[tr]
	[td]Function RepeatCount(Rng As Range) As String
  Dim Cell As Range, Tmp As Variant
  With CreateObject("Scripting.Dictionary")
    For Each Cell In Rng
      If Len(Cell.Value) Then .Item(CStr(Cell.Value)) = .Item(CStr(Cell.Value)) + 1
    Next
    RepeatCount = Join(Filter(.Items, 1, False), "")
    If Len(RepeatCount) Then RepeatCount = RepeatCount & "R"
  End With
End Function[/td]
[/tr]
[/table]
 
Upvote 0

Forum statistics

Threads
1,224,824
Messages
6,181,186
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

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