Forum Discussion

JayNixon's avatar
JayNixon
Copper Contributor
Jul 15, 2019
Solved

Concatenating column B values if left adjacent cell is empty

I need to combine cells in column B if the value in the cell to the left is blank while also deleting the blank cell to the left to close any gaps between cells in Column A. The best way for me to explain this is by showing an example. I need this:

 

Column A             Column B

Test                      This

                             That

                             Other

Test2                    Also

                             This

Test3                    Please

                             Help

                             Me

 

To look like this

 

Column A                    Column B

Test                              This, That, Other

Test2                            Also, This

Test3                            Please, Help, Me

 

 

I am not quite sure how to word my question to search so I apologize if this has been asked many times! :)

  • JayNixon

    I revised the macro to allow up to 200 more rows of results in case of overflow, as well as up to 165 characters in next pass through the concatenation loop. When an overflow situation is detected, the server name will be repeated as often as needed to get all software names listed on additional rows.

    Sub Sequelize()
    Dim rg As Range
    Dim delimiter As String, s As String
    Dim i As Long, k As Long, n As Long, nData As Long
    Dim vData As Variant, vResults As Variant
    
    delimiter = ", "
    Set rg = Range("A2").CurrentRegion
    Set rg = rg.Offset(1, 0).Resize(rg.Rows.Count - 1, rg.Columns.Count)
    n = rg.Rows.Count
    nData = Application.CountA(rg.Columns(1))
    nData = nData + 200 'Allow for servers whose software list exceeds 32,767 characters
    vData = rg.Value
    ReDim vResults(1 To nData, 1 To 2)
    
    For i = 1 To n
        If vData(i, 1) <> "" Then
            k = k + 1
            vResults(k, 1) = vData(i, 1)
            If s <> "" Then
                If i > 1 Then vResults(k - 1, 2) = Left$(s, 32767)
            End If
            s = IIf(vData(i, 2) = "", "", vData(i, 2))
        Else
            If vData(i, 2) <> "" Then
                If s = "" Then
                    s = vData(i, 2)
                Else
                    s = s & delimiter & vData(i, 2)
                End If
            End If
        End If
        
        'Overflow occurs if you put more than  32,767 characters in a cell. This block allows up to 165 characters (plus delimiter) in next pass through loop.
        If Len(s) > 32600 Then
            If (i < n) And (vData(i + 1, 1) = "") Then
                vResults(k, 2) = s
                vResults(k + 1, 1) = vResults(k, 1)
                s = ""
                k = k + 1
            End If
        End If
    Next
    If s <> "" Then vResults(k, 2) = Left$(s, 32767)
    
    rg.ClearContents
    rg.Resize(nData, 2).Value = vResults
    End Sub

39 Replies

  • JayNixon 

    Hi Jay,

    there are a solution with help of the follwing macro:

    Sub GroupData()
    Dim lngRow As Long
    Dim lngRowMax As Long
    Dim lngz As Long
    Dim lngzMax As Long

    With Sheet1
    .Range("G:H").ClearContents
    .Range("G1:H1").Value = .Range("A1:B1").Value
    lngz = 2
    lngRowMax = .Range("B" & .Rows.Count).End(xlUp).Row

    For lngRow = 2 To lngRowMax
    If .Range("A" & lngRow).Value <> "" Then
    .Range("G" & lngz).Value = .Range("A" & lngRow).Value
    .Range("H" & lngz).Value = .Range("B" & lngRow).Value
    lngz = lngz + 1
    Else
    lngzMax = .Range("H" & .Rows.Count).End(xlUp).Row
    .Range("H" & lngzMax).Value = .Range("H" & lngzMax).Value & "," & .Range("B" & lngRow).Value
    End If

    Next lngRow

    End With

    End Sub

    Best regards
    Bernd
    https://vba-tanker.com/

     

    • Brad_Yundt's avatar
      Brad_Yundt
      MVP

      If you prefer a macro to concatenate, then consider:

      Sub Sequelize()
      Dim rg As Range, targ As Range
      Dim delimiter As String, s As String
      Dim i As Long, j As Long, n As Long
      
      delimiter = ", "
      Set rg = Range("A2").CurrentRegion
      Set rg = rg.Offset(1, 0).Resize(rg.Rows.Count - 1, rg.Columns.Count)
      n = rg.Rows.Count
      j = 1
      For i = n To 1 Step -1
          If rg.Cells(i, 1).Value <> "" Then
              rg.Rows(i + 1).Resize(j - 1).EntireRow.Delete
              If rg.Cells(i, 2).Value <> "" Then s = rg.Cells(i, 2).Value & delimiter & s
              If s <> "" Then rg.Cells(i, 2).Value = Left(s, Len(s) - Len(delimiter))
              j = 1
              s = ""
          Else
              j = j + 1
              If rg.Cells(i, 2).Value <> "" Then s = rg.Cells(i, 2).Value & delimiter & s
          End If
      Next
      End Sub
      • JayNixon's avatar
        JayNixon
        Copper Contributor

        Thank you Brad_Yundt. I am trying to test this now on my actual worksheet and the only problem I am having is that the sheet is 260,000 rows and my computer will freeze every time I try anything. 

    • JayNixon's avatar
      JayNixon
      Copper Contributor

      Thanks for responding so quickly SergeiBaklan. I am pretty green when it comes to excel but have been working with it extensively in my new position. If you have the time, could you explain Power Query a bit more? I would like to know more about it from someone who has obviously used it.

      • SergeiBaklan's avatar
        SergeiBaklan
        Diamond Contributor

        JayNixon 

        Power Query - you may start from Getting Started with Get & Transform in Excel ,it gives the main idea. Technology requires some time to invest, but you may start doing something practical from very first steps.

         

        For this sample you may open the query (Data->Queries $ Connections, double click on query in the right pane) and check step by step what it's doing.

  • JayNixon 

    If you want a formula to return your concatenated text and have Excel 2016 on Office 365 subscription (or Excel 2019), then you may copy down a TEXTJOIN formula:

    =TEXTJOIN(",",TRUE,INDEX(B:B,MATCH(D2,A:A,0)):INDEX(B:B,IFERROR(MATCH(D3,A:A,0)-1,MAX(MATCH({"zzzzz",1E+307},B:B,1)))))
    • JayNixon's avatar
      JayNixon
      Copper Contributor

      Thanks Brad_Yundt  for your quick response here. I am trying this formula now. I am a novice when it comes to excel so I have a few questions.

      I tried running that formula is column C and the return is #N/A. What do I need to change here?

      Is column C the correct column?

       

      Thanks in advance.

      • Brad_Yundt's avatar
        Brad_Yundt
        MVP

        JayNixon 

        The formula was assuming that you already had the column A values listed as in your initial post.

         

        When you subsequently changed your question, I wrote a macro to do the new  request.

         

        The attached workbook shows both the macro and the formula.

Resources