Forum Discussion
Concatenating column B values if left adjacent cell is empty
- Jul 16, 2019
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
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.
- Brad_YundtJul 15, 2019MVP
My most recent macro is working on your test workbook. I installed the code, added a button to call it in the attached workbook so you may test. The duplicate data off to the right is so I can easily restore the original condition.
Brad
- JayNixonJul 15, 2019Copper ContributorI just ran it on my actual worksheet and it deleted everything below row 1. I may not be executing this properly. I went to view macros, create, pasted in the macro from above, saved it, then ran that macro. I assume this is how I am supposed to do it but maybe I am incorrect. Also my actual worksheet has 260,000 rows of data but that shouldn't affect it, correct?
- Brad_YundtJul 15, 2019MVP
The macro assumes your data starts in row 2 and that header labels are in row 1. It further assumes that you have no blank lines in your data, and that there are only two columns of data.
Your question said that you wanted to start with two columns of data in columns A and B, then end up with two columns of compacted results in columns A and B. That's what the macro does.
The third from the last statement in the macro deletes the existing data (except header labels). The next to last statement puts the compacted results starting in cell A2. If you want them moved elsewhere, that statement is easily changed.
I made 6270 copies of your data, filling the sheet past row 260000 and ran the macro. It completed work in less than a second.