VBA Macro to comment cells according to its value

vabtroni

New Member
Joined
Aug 1, 2017
Messages
32
Office Version
  1. 365
Platform
  1. Windows
Hello everyone!

I need a VBA code to comment cells on a certain range according to its value, and the content of the comment is given in another table. Please follow the example:

example_1.jpg


The table on the left is used to assign vehicles to a certain service. The table on the right has remarks about each vehicle. When I press the "UPDATE REMARKS" button, I want it to run a macro that does the following:

1) Clear all previous coments (if any) on range A4:A8
2) On range A4:A8 , comment the vehicle remarks, so that the final work looks like this:

(for the coding, ignore the red circle and arrow, as they are just to show what is to place where :) )

example_2.jpg


example_3.jpg


Thank you all in advance, best regards and stay safe, mates!
Cheers! :)
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,406
Office Version
  1. 365
Platform
  1. Windows
How about
VBA Code:
Sub vabtroni()
   Dim Cl As Range
   
   With CreateObject("scripting.dictionary")
      For Each Cl In Range("D4:D8")
         .Item(Cl.Value) = Cl.Offset(, 1).Value
      Next Cl
      For Each Cl In Range("A4:A8")
         If Not Cl.Comment Is Nothing Then Cl.Comment.Delete
         If .Exists(Cl.Value) Then
            Cl.AddComment
            Cl.Comment.Text .Item(Cl.Value)
         End If
      Next Cl
   End With
End Sub
 

vabtroni

New Member
Joined
Aug 1, 2017
Messages
32
Office Version
  1. 365
Platform
  1. Windows
Worked just fine!! Thank you very much, Fluff!! :)
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,406
Office Version
  1. 365
Platform
  1. Windows
You're welcome & thanks for the feedback.
 

vabtroni

New Member
Joined
Aug 1, 2017
Messages
32
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

Hello everyone, hello Fluff.

I've just stopped into a flaw. For example, if I don't have a vehicle assigned to the south route (meaning cell A5 will be empty), when I run the macro it returns me error "400". Considering the fact that the code will change a bit, it would also be nice to ignore empty cells on range D4:D8, as I believe it could comment empty cells on the target area with a blank comment.

So, the new logical steps would be the following:

1) Clear all previous coments (if any) on range A4:A8, even on empty cells;
2) On range A4:A8 , comment the vehicle remarks. If any cell on this range is empty, do nothing and proceed to next cell, etc etc. Also, ignore empty cells on range D4:D8 when reading the remarks.

Any way we could work around with these new premisses?

Thanks in advance,
V.
 

vabtroni

New Member
Joined
Aug 1, 2017
Messages
32
Office Version
  1. 365
Platform
  1. Windows
Also, another question: I have a file for each week, meaning I have several sheets on the same workbook, one for each day of the week.

Should the code be put into a module, into the workbook, or put it in every sheet where it can run?
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,406
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

How about
VBA Code:
Sub vabtroni()
   Dim cl As Range
   
   With CreateObject("scripting.dictionary")
      For Each cl In Range("D4:D8")
         If cl.Value <> "" Then .Item(cl.Value) = cl.Offset(, 1).Value
      Next cl
      For Each cl In Range("A4:A8")
         If Not cl.Comment Is Nothing Then cl.Comment.Delete
         If .Exists(cl.Value) And .Item(cl.Value) <> "" Then
            cl.AddComment
            cl.Comment.Text .Item(cl.Value)
         End If
      Next cl
   End With
End Sub
If you put it in a standard module, then you can use it for any sheet as it will run on the active sheet.
 

vabtroni

New Member
Joined
Aug 1, 2017
Messages
32
Office Version
  1. 365
Platform
  1. Windows
Perfect, so far. Thank you very much once again, Fluff. :) (y)🤓
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,406
Office Version
  1. 365
Platform
  1. Windows
My pleasure.
 

vabtroni

New Member
Joined
Aug 1, 2017
Messages
32
Office Version
  1. 365
Platform
  1. Windows
Sorry to bother, just another one here, related to your code.

I have a macro that adds a thick pink border to the "current selection". Lets say this macro is called "paint".

At some point on your code, I'd like it to run that macro for the current range, ie:

VBA Code:
Sub vabtroni()
   Dim cl As Range
   
   With CreateObject("scripting.dictionary")
      For Each cl In Range("D4:D8")
         If cl.Value <> "" Then .Item(cl.Value) = cl.Offset(, 1).Value
      Next cl
      For Each cl In Range("A4:A8")
         If Not cl.Comment Is Nothing Then cl.Comment.Delete
         If .Exists(cl.Value) And .Item(cl.Value) <> "" Then
            cl.AddComment
            cl.Comment.Text .Item(cl.Value)
            ' RUN MACRO HERE FOR CURRENT cl.
         End If
      Next cl
   End With
End Sub

The result will be a comment on that cell, as well as that thick pink border.

What would be the correct synthax for that to happen?
 

Watch MrExcel Video

Forum statistics

Threads
1,129,260
Messages
5,635,131
Members
416,842
Latest member
Ateen4ever

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
Top