Assistance to write a Macro that turns multiple lines of strings into one string based on corresponding ID#s

murphman25

New Member
Joined
May 25, 2018
Messages
2
Hi all! New to the forum, and I have a question about creating a macro.


We have techs in the field collecting data about timber. Each day, we export that data to spreadsheets (images of the relevant sheets below). The way the recorders work, a certain field (Plot) has data (comments) that are output on a separate sheet in the workbook. If the comment is longer than 24 characters, the program creates a new line, preceded by a cell that contains the number of the plot it corresponds to.



What I am trying to accomplish is write a macro that will scan the ‘Plot’ column in the ‘Plot Comments’ sheet and concatenate any comments that have identical plot numbers and output the created string into a blank column (N) on the ‘Plot’ sheet on the line that corresponds to that same plot number, then delete those lines that were concatenated.



I’m trying to figure out the VBA syntax for Excel. I’m sure I could figure it out from resources on this forum and elsewhere, but I’m pinched for time to solve this problem before our QA team arrives. Any thoughts from the Mr.Excel community? Thanks in advance, folks!

Thanks, Murph

Sheet images:

Plot sheet:
https://drive.google.com/file/d/1WTqBAt3FdekUZcBb83NZlBNZ_SmkMsE5/view?usp=sharing

Plot comments sheet:
https://drive.google.com/file/d/1CK-HvOpnleYM9BQVlgs8RnxJXU8dftkU/view?usp=sharing

<style type="text/css">p { margin-bottom: 0.1in; line-height: 120%; }a:link { }</style>
 

Some videos you may like

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
44,404
Office Version
365
Platform
Windows
Welcome to the MrExcel board!

Preliminary comments:
- For the future, you will get many more potential helpers if you can provide your sample data in a form that can be copied/pasted to test with. Can't do that from images like you posted (hence my limited sample data below). My signature block at the bottom of the post has a link with suggestions.
- I have assumed that your data is not very large. That is, not thousands or tens of thousands of rows. If it is large there would faster ways than the code I have suggested below which should be plenty fast enough for reasonably small data.

Here is my code for testing in a copy of your workbook.
Code:
Sub Arrange_Comments()
  Dim d As Object
  Dim c As Range
  
  Set d = CreateObject("Scripting.Dictionary")
  With Sheets("Plot Comments")
    For Each c In .Range("D2", .Range("D" & .Rows.Count).End(xlUp))
      d(c.Value) = d(c.Value) & " " & c.Offset(, 1).Value
    Next c
  End With
  With Sheets("Plot")
    For Each c In .Range("D2", .Range("D" & .Rows.Count).End(xlUp))
      If d.exists(c.Value) Then .Range("N" & c.Row).Value = Mid(d(c.Value), 2)
    Next c
  End With
End Sub
<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>D</th><th>E</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style="text-align: right;;">Plot</td><td style=";">Comments</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style="text-align: right;;">730</td><td style=";">Comment Line 1</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style="text-align: right;;">730</td><td style=";">Comment Line 2</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style="text-align: right;;">730</td><td style=";">Comment Line 3</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">5</td><td style="text-align: right;;">950</td><td style=";">Comment Line 4</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">6</td><td style="text-align: right;;">1115</td><td style=";">Comment Line 5</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">7</td><td style="text-align: right;;">1115</td><td style=";">Comment Line 6</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">8</td><td style="text-align: right;;">3000</td><td style=";">Comment Line 7</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">9</td><td style="text-align: right;;">3000</td><td style=";">Comment Line 8</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">10</td><td style="text-align: right;;">3000</td><td style=";">Comment Line 9</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">11</td><td style="text-align: right;;">3000</td><td style=";">Comment Line 10</td></tr></tbody></table><p style="width:10.4em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Plot Comments</p><br /><br />


<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>D</th><th>N</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style="text-align: right;;">Plot</td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style="text-align: right;;">730</td><td style=";">Comment Line 1 Comment Line 2 Comment Line 3</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style="text-align: right;;">800</td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style="text-align: right;;">910</td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">5</td><td style="text-align: right;;">950</td><td style=";">Comment Line 4</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">6</td><td style="text-align: right;;">1115</td><td style=";">Comment Line 5 Comment Line 6</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">7</td><td style="text-align: right;;">2000</td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">8</td><td style="text-align: right;;">3000</td><td style=";">Comment Line 7 Comment Line 8 Comment Line 9 Comment Line 10</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">9</td><td style="text-align: right;;">4000</td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:3.2em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Plot</p><br /><br />
 

murphman25

New Member
Joined
May 25, 2018
Messages
2
Peter-
Oops! Yes, I shold have realized the data in the screenshots wasn't useful...I wad rushing as our satellite internet out here was very spotty this week. Thanks both for pointing that out and taking the time to create your own data! I'll make sure I don't do that in the future.

Your script works great. I haven't used a dictionary in VBA before-- I learned a lot about that today in understanding your code. I used the same approach to write the macro for our Tree Comments-->Tree sheets by increasing the offset to reflect the different column layout. Thanks, Peter!
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
44,404
Office Version
365
Platform
Windows
Your script works great. I haven't used a dictionary in VBA before-- I learned a lot about that today in understanding your code. I used the same approach to write the macro for our Tree Comments-->Tree sheets by increasing the offset to reflect the different column layout. Thanks, Peter!
You are welcome, glad to help & also that you were also able to adapt the code to another situation. :)

If you haven't found it already, here is one resource you might find useful in relation to dictionaries: http://www.snb-vba.eu/VBA_Dictionary_en.html#L_1
 

Watch MrExcel Video

Forum statistics

Threads
1,095,234
Messages
5,443,274
Members
405,222
Latest member
Summer01

This Week's Hot Topics

  • Copy entire row if CountA <>0 to another sheet
    [B]I want to copy entire row if CountA <>0 for column J7:AM7 (headers on J6:AM6) and so on till the last used cell is column D and paste the...
  • Select last used Row in Table
    I have created a Table in a Worksheet which is locked to prevent user errors and protect formula. Some of the cells require freetext entries which...
  • excel workbook: do not allow certain file name
    Hello all, Don't think this has ever been asked before, but how do I restrict file save [Before_Save Event] if the name of the file being saved...
  • fixing problem autofilter
    hello i need help about my code when i search by code in textbox it doesn't show anything this is my data [ATTACH type="full"...
  • “Weight”
    Hi, i’ve got a long sheet filled with weights such as kg,g,L & ml. i can build a formula to convert kg into g and liter into ml. How ever, my...
  • How to capitalize everything before a certain character?
    In column A, I have some text: Hello good day.mp3 Hello good day.flac etc. I'd like to capitalize everything before the period. I don't need the...
Top