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>
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
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


Book1
DE
1PlotComments
2730Comment Line 1
3730Comment Line 2
4730Comment Line 3
5950Comment Line 4
61115Comment Line 5
71115Comment Line 6
83000Comment Line 7
93000Comment Line 8
103000Comment Line 9
113000Comment Line 10
Plot Comments




Book1
DN
1Plot
2730Comment Line 1 Comment Line 2 Comment Line 3
3800
4910
5950Comment Line 4
61115Comment Line 5 Comment Line 6
72000
83000Comment Line 7 Comment Line 8 Comment Line 9 Comment Line 10
94000
Plot
 
Upvote 0
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!
 
Upvote 0
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
 
Upvote 0

Forum statistics

Threads
1,223,896
Messages
6,175,265
Members
452,627
Latest member
KitkatToby

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