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
You have done it! Thank you for your dedication to this issue of mine. This works perfectly. Brad_Yundt
If not a secret, what's the reason keep list of server software in so long strings instead of columns cell?
- JayNixonJul 16, 2019Copper Contributor
Yeah, unfortunately I am working with such a large amount of data here that it doesn't want to cooperate by making it easy and convenient to read. There are thousands of servers and the software includes everything from Google Chrome to .net framework updates to security updates for various tools. But what I have now is the easiest to search through I believe. I can query the inventory for a server and then it will just show me the column(s) of data associated with it. From there I can just Ctrl+F to search more specifically. Thanks for trying to help me with my issue. I appreciate it. I have much to learn!!
- SergeiBaklanJul 16, 2019MVP
I see, thank you for the explanation. Perhaps servers in columns will be more compact and searchable, but it all depends on your concrete data.
- JayNixonJul 16, 2019Copper Contributor
I am importing this into a sharepoint webpage through the excel app and if I kept all the applications in columns then some of the servers would have 100+ columns. I am positive there is a better way to accomplish my task but am a new intern and I lack the knowledge to do so. :/