vba to highlight the difference between text strings in two ranges

cjcass

Well-known Member
Joined
Oct 27, 2011
Messages
679
Office Version
  1. 2016
Platform
  1. Windows
I have the code below that highlights the differences between text strings in two ranges, however it's flawed because it will highlight everything after it finds the first element of difference in the string. Is there some code addition/change that can achieve a more exact result?

It currently does this:
A1: The quick brown fox jumped over the lazy dog
B1: The quick brown kangaroo jumped over the lazy dog

But I need it to do this:
A1: The quick brown fox jumped over the lazy dog
B1: The quick brown kangaroo jumped over the lazy dog

Any help much appreciated.

VBA Code:
Sub highlight()
    Dim xRg1 As Range
    Dim xRg2 As Range
    Dim xTxt As String
    Dim xCell1 As Range
    Dim xCell2 As Range
    Dim i As Long
    Dim J As Integer
    Dim xLen As Integer
    Dim xDiffs As Boolean
    On Error Resume Next
    If ActiveWindow.RangeSelection.Count > 1 Then
      xTxt = ActiveWindow.RangeSelection.AddressLocal
    Else
      xTxt = ActiveSheet.UsedRange.AddressLocal
    End If
lOne:
    Set xRg1 = Application.InputBox("Range A:", "Excel", xTxt, , , , , 8)
    If xRg1 Is Nothing Then Exit Sub
    If xRg1.Columns.Count > 1 Or xRg1.Areas.Count > 1 Then
        MsgBox "Multiple ranges or columns have been selected ", vbInformation, "Excel"
        GoTo lOne
    End If
lTwo:
    Set xRg2 = Application.InputBox("Range B:", "Excel", "", , , , , 8)
    If xRg2 Is Nothing Then Exit Sub
    If xRg2.Columns.Count > 1 Or xRg2.Areas.Count > 1 Then
        MsgBox "Multiple ranges or columns have been selected ", vbInformation, "Excel"
        GoTo lTwo
    End If
    If xRg1.CountLarge <> xRg2.CountLarge Then
       MsgBox "Two selected ranges must have the same numbers of cells ", vbInformation, "Excel"
       GoTo lTwo
    End If
    xDiffs = (MsgBox("Click Yes to highlight similarities, click No to highlight differences ", vbYesNo + vbQuestion, "Excel") = vbNo)
    Application.ScreenUpdating = False
    xRg2.Font.ColorIndex = xlAutomatic
    For i = 1 To xRg1.Count
        Set xCell1 = xRg1.Cells(i)
        Set xCell2 = xRg2.Cells(i)
        If xCell1.Value2 = xCell2.Value2 Then
            If Not xDiffs Then xCell2.Font.Color = vbRed
        Else
            xLen = Len(xCell1.Value2)
            For J = 1 To xLen
                If Not xCell1.Characters(J, 1).Text = xCell2.Characters(J, 1).Text Then Exit For
            Next J
            If Not xDiffs Then
                If J <= Len(xCell2.Value2) And J > 1 Then
                    xCell2.Characters(1, J - 1).Font.Color = vbRed
                End If
            Else
                If J <= Len(xCell2.Value2) Then
                    xCell2.Characters(J, Len(xCell2.Value2) - J + 1).Font.Color = vbRed
                End If
            End If
        End If
    Next
    Application.ScreenUpdating = True
End Sub
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Hi, a VBA demonstration according to range A1:B1 as a starting point :​
VBA Code:
Sub Demo1()
    Dim S&, V, L&
        S = 1
    With [A1:B1]
            With .Cells(2).Font:  .Bold = False:  .ColorIndex = xlAutomatic:  End With
            V = .Value2
            V(1, 1) = Split(V(1, 1))
            V(1, 2) = Split(V(1, 2))
            If LBound(V(1, 1)) + LBound(V(1, 2)) < 0 Or UBound(V(1, 1)) <> UBound(V(1, 2)) Then Beep: Exit Sub
        For N = 0 To UBound(V(1, 2))
            L = Len(V(1, 2)(N))
            If V(1, 2)(N) <> V(1, 1)(N) Then With .Cells(2).Characters(S, L).Font: .Bold = True: .Color = vbRed: End With
            S = S + L + 1
        Next
    End With
End Sub
 
Upvote 0
What result(s) would you want for this?

A1: The quick brown fox jumped over the lazy dog
B1: The quick black dog walked the lazy fox over the road
 
Upvote 0
What result(s) would you want for this?

A1: The quick brown fox jumped over the lazy dog
B1: The quick black dog walked the lazy fox over the road
Good question, I guess I'd be looking for this...

A1: The quick brown fox jumped over the lazy dog
B1: The quick black dog walked the lazy fox over the road

Due to the complexity of possibilities I'm happy to have some kind of limitation to what the code can achieve as long as I understand it, if that makes sense
 
Upvote 0
Good question, I guess I'd be looking for this...

A1: The quick brown fox jumped over the lazy dog
B1: The quick black dog walked the lazy fox over the road

Due to the complexity of possibilities I'm happy to have some kind of limitation to what the code can achieve as long as I understand it, if that makes sense

I also need it to highlight part of words and characters if that's possible
 
Upvote 0
Hi, a VBA demonstration according to range A1:B1 as a starting point :​
VBA Code:
Sub Demo1()
    Dim S&, V, L&
        S = 1
    With [A1:B1]
            With .Cells(2).Font:  .Bold = False:  .ColorIndex = xlAutomatic:  End With
            V = .Value2
            V(1, 1) = Split(V(1, 1))
            V(1, 2) = Split(V(1, 2))
            If LBound(V(1, 1)) + LBound(V(1, 2)) < 0 Or UBound(V(1, 1)) <> UBound(V(1, 2)) Then Beep: Exit Sub
        For N = 0 To UBound(V(1, 2))
            L = Len(V(1, 2)(N))
            If V(1, 2)(N) <> V(1, 1)(N) Then With .Cells(2).Characters(S, L).Font: .Bold = True: .Color = vbRed: End With
            S = S + L + 1
        Next
    End With
End Sub
Hi,
To extend this code to a larger range do I simply change the [A1:B1] to say [A10:B50]...?
 
Upvote 0
According to A1: The quick brown fox jumped over the lazy dog​
and B1: The quick black dog walked the lazy fox over the road​
another VBA demonstration for starters :​
VBA Code:
Sub Demo2()
    Dim S&, V, W, L&, X
        S = 1
    With [A1:B1]
            With .Cells(2).Font:  .Bold = False:  .ColorIndex = xlAutomatic:  End With
            V = .Value2
            V(1, 1) = Application.Index(Split(V(1, 1)), 1, 0)
        For Each W In Split(V(1, 2))
            L = Len(W)
            X = Application.Match(W, V(1, 1), 0)
            If IsError(X) Then With .Cells(2).Characters(S, L).Font: .Bold = True: .Color = vbRed: End With Else V(1, 1)(X) = Empty
            S = S + L + 1
        Next
    End With
End Sub
 
Upvote 0
According to A1: The quick brown fox jumped over the lazy dog​
and B1: The quick black dog walked the lazy fox over the road​
another VBA demonstration for starters :​
VBA Code:
Sub Demo2()
    Dim S&, V, W, L&, X
        S = 1
    With [A1:B1]
            With .Cells(2).Font:  .Bold = False:  .ColorIndex = xlAutomatic:  End With
            V = .Value2
            V(1, 1) = Application.Index(Split(V(1, 1)), 1, 0)
        For Each W In Split(V(1, 2))
            L = Len(W)
            X = Application.Match(W, V(1, 1), 0)
            If IsError(X) Then With .Cells(2).Characters(S, L).Font: .Bold = True: .Color = vbRed: End With Else V(1, 1)(X) = Empty
            S = S + L + 1
        Next
    End With
End Sub
Thanks for this, how do I extend this code to cover a much larger range? I change the [A1:B1] to [A10:B50] but it still only works for [A1:B1].
 
Upvote 0

Just compare columns A & B of each row …​
 
Upvote 0

Forum statistics

Threads
1,214,920
Messages
6,122,267
Members
449,075
Latest member
staticfluids

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