Sub MyConditionalFormatting()
Dim myLastRow As Long
Dim i As Long
Dim j As Long
Dim myFormula As String
' Clear all existing conditional formatting
Cells.FormatConditions.Delete
' Find last row with data in column A
myLastRow = Cells(Rows.Count, "A").End(xlUp).Row
' Start at first row in column A after a blank with data
i = Range("A1").End(xlDown).Row
' Loop through all data until end
Do Until i >= myLastRow
' Find last row in current block
j = Range("A" & i).End(xlDown).Row
' Build conditional formula to use
myFormula = "=LEFT(A" & i & ",1)=LEFT(A$" & i & ",1)"
' Set range of current block
Range("A" & i & ":A" & j).Select
' Apply formula to range
Selection.FormatConditions.Add Type:=xlExpression, Formula1:=myFormula
Selection.FormatConditions(Selection.FormatConditions.Count).SetFirstPriority
With Selection.FormatConditions(1).Interior
.PatternColorIndex = xlAutomatic
.Color = 65535
.TintAndShade = 0
End With
Selection.FormatConditions(1).StopIfTrue = False
' Find the start of the next block
i = Range("A" & j).End(xlDown).Row
Loop
'
End Sub