electricpete
Electrical
- May 4, 2001
- 16,774
I'd be interested to hear if you have any general purpose excel vba routines that you find especially helpful
The one I'll present is one that was discussed in another thread thread770-485250
In there I had presented a cell highlighter routine so you can keep track of the current cell if you have multiple windows open (excel's built in current-cell highlighter disappears if you shift focus to another window).
That previous version did have the undesirable characteristic of wiping out some existing formatting of the sheet.
3DDave made a comment which suggested that conditional formatting could overcome that limitation.
I have redone that code to use conditional formatting for highlighting, and that fixed the problem, it doesn't interfere with formatting (minor exception at the end):
[ul]
[li]It doesn't wipe out any existing permanent formatting.[/li]
[li]It doesn't wipe out any existing conditional formatting (I wasn't as sure of this, but my experimentation supports the conclusion.[/li]
[li]It doesn't interfere with using the paintbrush formatter tool to paste format from current selection to another location in the same sheet.[/li]
[li]...(even though you can't see the format while your cursor is in that cell due to the highlighting).[/li]
[li]It DOES interfere with using the paintbrush formatter tool to paste format from current selection to another location in a DIFFERENT sheet[/li]
[li]... (because the target sheet doesn't have the same macro to help clear out that cell highlighting format)[/li]
[li]... I don't think it's a big problem, just don't paste formats from the highlighter sheet into a different sheet[/li]
[li]... ... the fact that you have a big yellow highlight in the cell is an obvious clue that naturally reminds you to think about effects of copying format from that cell[/li]
[/ul]
It only works on one sheet, not a whole workbook.
Below is the new code, which should be pasted into the code area for a particular sheet, NOT into a module area.
Let me know if you have any problem with it. And let us know your own favorite general purpose vba routines
=====================================
(2B)+(2B)' ?
The one I'll present is one that was discussed in another thread thread770-485250
In there I had presented a cell highlighter routine so you can keep track of the current cell if you have multiple windows open (excel's built in current-cell highlighter disappears if you shift focus to another window).
That previous version did have the undesirable characteristic of wiping out some existing formatting of the sheet.
3DDave made a comment which suggested that conditional formatting could overcome that limitation.
I have redone that code to use conditional formatting for highlighting, and that fixed the problem, it doesn't interfere with formatting (minor exception at the end):
[ul]
[li]It doesn't wipe out any existing permanent formatting.[/li]
[li]It doesn't wipe out any existing conditional formatting (I wasn't as sure of this, but my experimentation supports the conclusion.[/li]
[li]It doesn't interfere with using the paintbrush formatter tool to paste format from current selection to another location in the same sheet.[/li]
[li]...(even though you can't see the format while your cursor is in that cell due to the highlighting).[/li]
[li]It DOES interfere with using the paintbrush formatter tool to paste format from current selection to another location in a DIFFERENT sheet[/li]
[li]... (because the target sheet doesn't have the same macro to help clear out that cell highlighting format)[/li]
[li]... I don't think it's a big problem, just don't paste formats from the highlighter sheet into a different sheet[/li]
[li]... ... the fact that you have a big yellow highlight in the cell is an obvious clue that naturally reminds you to think about effects of copying format from that cell[/li]
[/ul]
It only works on one sheet, not a whole workbook.
Below is the new code, which should be pasted into the code area for a particular sheet, NOT into a module area.
Let me know if you have any problem with it. And let us know your own favorite general purpose vba routines
Code:
Sub Worksheet_SelectionChange(ByVal Target As Excel.Range)
' Current Cell row/column highlighter
' update 072121 - uses conditional formating, and "union"
' Usage note - if for some reason a cell remains highlighted
' ... which is not the current cell, then fix it by
' ... clicking on that cell and then clicking on any other cell
Static lastRow, lastCol ' Holds the cell coordinates from last call to sub
Dim mySheet As Sheet1
Dim thisRange, lastRange As Range
Dim thisFC, lastFC As FormatCondition
Set mySheet = Target.Parent
' Clear highlighting from last (previous) cell from last call to this function:
If lastRow <> "" Then ' don't proceed if empty values (when initially open workbook)
Set lastRange = Union(mySheet.Rows(lastRow), mySheet.Columns(lastCol)) ' builds a range that highlights both row and column of last cell
With lastRange
For Each lastFC In .FormatConditions
If lastFC.Type = xlExpression And (lastFC.Formula1 = "=ROW()>0") Then
lastFC.Delete
End If
Next lastFC
End With
End If
' Highlight current cell:
Set thisRange = Union(mySheet.Rows(Target.Row), mySheet.Columns(Target.Column)) ' builds a range that highlights both row and column of current cell
Set thisFC = thisRange.FormatConditions.Add(Type:=xlExpression, Formula1:="=ROW()>0")
With thisFC
.SetFirstPriority
With .Interior
.Color = vbYellow
.Pattern = xlSolid
End With
End With
' Save lastRow and lastCol for the next call...
lastRow = Target.Row
lastCol = Target.Column
End Sub
=====================================
(2B)+(2B)' ?