Okay, let's try this.
Place the following code in the ThisWorkbook module of your file:
Code:
Option Explicit
Private Sub Workbook_Activate()
'Add custom menu items
With Application
.CommandBars("Cell").Reset
With .CommandBars("Cell").Controls
With .Add
.Caption = "Create Box"
.OnAction = ThisWorkbook.Name & "!CreateBox"
.Tag = "Create"
.BeginGroup = True
End With
With .Add
.Caption = "Restore Shelves"
.OnAction = ThisWorkbook.Name & "!RestoreShelves"
.Tag = "Restore"
End With
End With
End With
End Sub
Private Sub workbook_deactivate()
'Remove right click menu additions when workbook deactivated
Application.CommandBars("Cell").Reset
End Sub
And the following code in a standard Module:
Code:
Option Explicit
Private Sub CreateBox()
'Brown fill, black border around cell
With Selection
'Set fill color here
.Interior.Color = 9944516
With .Borders(xlEdgeLeft)
.LineStyle = xlContinuous
.Weight = xlThin
End With
With .Borders(xlEdgeRight)
.LineStyle = xlContinuous
.Weight = xlThin
End With
With .Borders(xlEdgeTop)
.LineStyle = xlContinuous
.Weight = xlThin
End With
With .Borders(xlEdgeBottom)
.LineStyle = xlContinuous
.Weight = xlThin
End With
With .Borders(xlInsideVertical)
.LineStyle = xlNone
End With
With .Borders(xlInsideHorizontal)
.LineStyle = xlNone
End With
End With
End Sub
Private Sub RestoreShelves()
'Change the selection border to a green thick line on the top and
'bottom, and an orange left and right side
'Won't touch the cell contents or the fill.
With Selection
With .Borders(xlEdgeLeft)
.Color = 682978
.LineStyle = xlContinuous
.Weight = xlThick
End With
With .Borders(xlEdgeRight)
.Color = 682978
.LineStyle = xlContinuous
.Weight = xlThick
End With
With .Borders(xlEdgeTop)
.Color = -11489280
.LineStyle = xlContinuous
.Weight = xlThick
End With
With .Borders(xlEdgeBottom)
.Color = -11489280
.LineStyle = xlContinuous
.Weight = xlThick
End With
With .Borders(xlInsideVertical)
.LineStyle = xlNone
End With
With .Borders(xlInsideHorizontal)
.LineStyle = xlNone
End With
End With
End Sub
If you need any help figuring out what goes where, this article may help.
The save the file as an xlsm file (so that the macros stay there), close it, and reopen it. You should now have two items at the bottom of your right click menu that will (hopefully) do what you're after.
Let me know if you need any more help with it.
Bookmarks