Split cell contents in different sets

Pete2020

Board Regular
Joined
Apr 25, 2020
Messages
68
Office Version
  1. 2016
Platform
  1. Windows
I am looking for a Excel Formula or function or VBA which is simple to understand. The actual data is Text and not a Numeric values

The cell contents is to be divided into different sets with flower brackets and a comma separator.
It should separate the data equally based on values in available based on "|" delimiter

Ex: Column A Row 1 ( Full range has around 10k Rows)
1|2|3|4|5|6|7|8|9|10|11|12|13|14|15|16|17|18|19|20|

After Applying formula or VBA code - The values shoule be equally divided and if not divisible it should fall under another curly bracket

In Column B Row1 the data should present with curly Brackets based on groups i mentioned in VBA or formula
{1|2|3|4|5},{6|7|8|9|10},{11|12|13|14|15},{16|17|18|19|20}
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Try this
VBA Code:
Sub Pete2020_Split()

Dim DTA() As Variant, SSP() As String, G As Long, K As Long, Build_STR As String, D_Count As Long, Output() As String

With Application
    .ScreenUpdating = False
    .Calculation = xlCalculationManual
End With

DTA = ActiveSheet.UsedRange.Value2

Const Delimiter As String = "|"

ReDim Output(1 To UBound(DTA, 1), 1 To 1)

For G = 1 To UBound(DTA, 1)

    SSP = Split(DTA(G, 1), "|")
    
    For K = LBound(SSP) To UBound(SSP)
    
        Select Case K

            Case LBound(SSP)

                Build_STR = "{" & SSP(K)

            Case UBound(SSP)
            
                If SSP(K) <> vbNullString Then
                    Build_STR = Build_STR & Delimiter & SSP(K) & "}"
                Else
                    Build_STR = Build_STR & "}"
                End If
                
                D_Count = 0
                
            Case Else
            
                Select Case D_Count 'count of "|" in the current group
                
                    Case 4
                    
                        Build_STR = Build_STR & "},{" & SSP(K)
                        D_Count = 0
                        
                    Case Else
                    
                        Build_STR = Build_STR & Delimiter & SSP(K)
                        D_Count = D_Count + 1
                        
                End Select

        End Select
        
    Next K
    
    Output(G, 1) = Build_STR
    Build_STR = vbNullString
    
Next G

ActiveSheet.Range("B1").Value2 = Output

With Application
    .ScreenUpdating = True
    .Calculation = xlCalculationAutomatic
End With

End Sub
 
Upvote 0
1|2|3|4|5|6|7|8|9|10|11|12|13|14|15|16|17|18|19|20|

What are the characteristics or patterns to divide the groups, your example can be divided in several ways:

{1|2|3|4|5|6|7|8|9|10} , {11|12|13|14|15|16|17|18|19|20} (2 groups of 10, are equal groups)
or
{1|2|3|4} , {5|6|7|8} , {9|10|11|12} , {13|14|15|16} , {17|18|19|20} (5 groups of 4, are equal groups)

And in the following example what would be the grouping:
1|2|3|4|5|6|7|8|9|10|11|12|13|14|15|16|17|
 
Upvote 0
t
What are the characteristics or patterns to divide the groups, your example can be divided in several ways:

{1|2|3|4|5|6|7|8|9|10} , {11|12|13|14|15|16|17|18|19|20} (2 groups of 10, are equal groups)
or
{1|2|3|4} , {5|6|7|8} , {9|10|11|12} , {13|14|15|16} , {17|18|19|20} (5 groups of 4, are equal groups)

And in the following example what would be the grouping:
1|2|3|4|5|6|7|8|9|10|11|12|13|14|15|16|17|

The Answer is 4 groups of 5 .

It is more helpful if the formula or VBA should provide a facility to update the groups to be splitted.
 
Upvote 0
Try this
VBA Code:
Sub Pete2020_Split()

Dim DTA() As Variant, SSP() As String, G As Long, K As Long, Build_STR As String, D_Count As Long, Output() As String

With Application
    .ScreenUpdating = False
    .Calculation = xlCalculationManual
End With

DTA = ActiveSheet.UsedRange.Value2

Const Delimiter As String = "|"

ReDim Output(1 To UBound(DTA, 1), 1 To 1)

For G = 1 To UBound(DTA, 1)

    SSP = Split(DTA(G, 1), "|")
   
    For K = LBound(SSP) To UBound(SSP)
   
        Select Case K

            Case LBound(SSP)

                Build_STR = "{" & SSP(K)

            Case UBound(SSP)
           
                If SSP(K) <> vbNullString Then
                    Build_STR = Build_STR & Delimiter & SSP(K) & "}"
                Else
                    Build_STR = Build_STR & "}"
                End If
               
                D_Count = 0
               
            Case Else
           
                Select Case D_Count 'count of "|" in the current group
               
                    Case 4
                   
                        Build_STR = Build_STR & "},{" & SSP(K)
                        D_Count = 0
                       
                    Case Else
                   
                        Build_STR = Build_STR & Delimiter & SSP(K)
                        D_Count = D_Count + 1
                       
                End Select

        End Select
       
    Next K
   
    Output(G, 1) = Build_STR
    Build_STR = vbNullString
   
Next G

ActiveSheet.Range("B1").Value2 = Output

With Application
    .ScreenUpdating = True
    .Calculation = xlCalculationAutomatic
End With

End Sub


Moshi, Once again thank You for giving macro.The VBA has hard coded.

I Kindly request to provide the macro,in such a way i can modify the No of groups it has to split.
 
Upvote 0
It is more helpful if the formula or VBA should provide a facility to update the groups to be splitted.

There are always 20 data and they are always divided into 5 groups of 4?

Or to which you refer with "facility" you could give more examples of what you have and what you expect from the result.
 
Upvote 0
Look for the variable Number_of_Elements_in_Group on the left and the corresponding comment in the code.
VBA Code:
Sub Pete2020_Split()

Dim DTA() As Variant, SSP() As String, G As Long, K As Long, Build_STR As String, _
D_Count As Long, Output() As String, Number_of_Elements_in_Group As Long

With Application
    .ScreenUpdating = False
    .Calculation = xlCalculationManual
End With

Number_of_Elements_in_Group = 5
'Or you can retrieve value from a cell like
'Number_of_Elements_in_Group = activesheet.range("C1").VALUE2
'Or from an inputbox.... Number_of_Elements_in_Group = clng(application.InputBox("Input number of of elements per group. Must be a number."))
DTA = ActiveSheet.UsedRange.Value2

Const Delimiter As String = "|"

ReDim Output(1 To UBound(DTA, 1), 1 To 1)

Number_of_Elements_in_Group=Number_of_Elements_in_Group-1

For G = 1 To UBound(DTA, 1)

    SSP = Split(DTA(G, 1), "|")
   
    For K = LBound(SSP) To UBound(SSP)
   
        Select Case K

            Case LBound(SSP)

                Build_STR = "{" & SSP(K)

            Case UBound(SSP)
           
                If SSP(K) <> vbNullString Then
                    Build_STR = Build_STR & Delimiter & SSP(K) & "}"
                Else
                    Build_STR = Build_STR & "}"
                End If
               
                D_Count = 0
               
            Case Else
           
                Select Case D_Count 'count of "|" in the current group
               
                    Case Number_of_Elements_in_Group
                   
                        Build_STR = Build_STR & "},{" & SSP(K)
                        D_Count = 0
                       
                    Case Else
                   
                        Build_STR = Build_STR & Delimiter & SSP(K)
                        D_Count = D_Count + 1
                       
                End Select

        End Select
       
    Next K
   
    Output(G, 1) = Build_STR
    Build_STR = vbNullString
   
Next G

ActiveSheet.Range("B1").Value2 = Output

With Application
    .ScreenUpdating = True
    .Calculation = xlCalculationAutomatic
End With

End Sub
 
Last edited:
Upvote 0
Look for the variable Number_of_Elements_in_Group on the left and the corresponding comment in the code.
VBA Code:
Sub Pete2020_Split()

Dim DTA() As Variant, SSP() As String, G As Long, K As Long, Build_STR As String, _
D_Count As Long, Output() As String, Number_of_Elements_in_Group As Long

With Application
    .ScreenUpdating = False
    .Calculation = xlCalculationManual
End With

Number_of_Elements_in_Group = 5
'Or you can retrieve value from a cell like
'Number_of_Elements_in_Group = activesheet.range("C1").VALUE2
'Or from an inputbox.... Number_of_Elements_in_Group = clng(application.InputBox("Input number of of elements per group. Must be a number."))
DTA = ActiveSheet.UsedRange.Value2

Const Delimiter As String = "|"

ReDim Output(1 To UBound(DTA, 1), 1 To 1)

Number_of_Elements_in_Group=Number_of_Elements_in_Group-1

For G = 1 To UBound(DTA, 1)

    SSP = Split(DTA(G, 1), "|")
  
    For K = LBound(SSP) To UBound(SSP)
  
        Select Case K

            Case LBound(SSP)

                Build_STR = "{" & SSP(K)

            Case UBound(SSP)
          
                If SSP(K) <> vbNullString Then
                    Build_STR = Build_STR & Delimiter & SSP(K) & "}"
                Else
                    Build_STR = Build_STR & "}"
                End If
              
                D_Count = 0
              
            Case Else
          
                Select Case D_Count 'count of "|" in the current group
              
                    Case Number_of_Elements_in_Group
                  
                        Build_STR = Build_STR & "},{" & SSP(K)
                        D_Count = 0
                      
                    Case Else
                  
                        Build_STR = Build_STR & Delimiter & SSP(K)
                        D_Count = D_Count + 1
                      
                End Select

        End Select
      
    Next K
  
    Output(G, 1) = Build_STR
    Build_STR = vbNullString
  
Next G

ActiveSheet.Range("B1").Value2 = Output

With Application
    .ScreenUpdating = True
    .Calculation = xlCalculationAutomatic
End With

End Sub

Thank You Moshi.
 
Upvote 0
Here another macro for you to consider.

In this line you can set the number of elements for each group
If n = 5 Then

VBA Code:
Sub splitCell()
  Dim a As Variant, b As Variant, c As String, sItems As Variant
  Dim i As Long, n As Long, j As Long
  a = Range("A1", Range("A" & Rows.Count).End(3)).Value2
  ReDim b(1 To UBound(a), 1 To 1)
  '
  For i = 1 To UBound(a)
    sItems = Split(a(i, 1), "|")
    c = "{"
    n = 0
    For j = 0 To UBound(sItems) - 1
      If n = 5 Then
        c = Left(c, Len(c) - 1) & "},{"
        n = 0
      End If
      c = c & sItems(j) & "|"
      n = n + 1
    Next
    b(i, 1) = Left(c, Len(c) - 1) & "}"
  Next
  '
  Range("B1").Resize(UBound(a)).Value = b
End Sub
 
Upvote 0
Here another macro for you to consider.

In this line you can set the number of elements for each group
If n = 5 Then

VBA Code:
Sub splitCell()
  Dim a As Variant, b As Variant, c As String, sItems As Variant
  Dim i As Long, n As Long, j As Long
  a = Range("A1", Range("A" & Rows.Count).End(3)).Value2
  ReDim b(1 To UBound(a), 1 To 1)
  '
  For i = 1 To UBound(a)
    sItems = Split(a(i, 1), "|")
    c = "{"
    n = 0
    For j = 0 To UBound(sItems) - 1
      If n = 5 Then
        c = Left(c, Len(c) - 1) & "},{"
        n = 0
      End If
      c = c & sItems(j) & "|"
      n = n + 1
    Next
    b(i, 1) = Left(c, Len(c) - 1) & "}"
  Next
  '
  Range("B1").Resize(UBound(a)).Value = b
End Sub

Thank You DanteAmor
 
Upvote 0

Forum statistics

Threads
1,213,514
Messages
6,114,078
Members
448,547
Latest member
arndtea

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