返回列表 上一主題 發帖

vba比對兩份資料是否一樣列出差異

vba比對兩份資料是否一樣列出差異

個位大神請教一下,我想要比對兩份資料是否一樣,列出差異部份,vba如何 Excel比對資料.rar (10.55 KB)

回復 1# aassddff736


    謝謝前輩發表此主題與範例
後學藉此帖練習陣列與字典,學習方案如下,請前輩參考

Option Explicit
Sub TEST1()
Dim Arr, Brr, Crr, K, Z, N&, i&, j%, R&, Ta$, Tb$, xR As Range
Set Z = CreateObject("Scripting.Dictionary")
Arr = Range([a資料!F1], [a資料!A65536].End(3)): Brr = Range([b資料!F1], [b資料!A65536].End(3))
ReDim Crr(1 To (UBound(Arr) + UBound(Brr)), 1 To 2)
For i = 2 To UBound(Arr)
   Ta = Trim(Arr(i, 1)): If Ta <> "" Then Z(Ta) = Z(Ta) + 1: Z(Ta & "/Ra") = i: Arr(i, 6) = "": R = R + 1: Crr(R, 1) = Ta: Crr(R, 2) = 1
Next
For i = 2 To UBound(Brr)
   Tb = Trim(Brr(i, 1)): If Z(Tb) = 0 Then R = R + 1: Crr(R, 1) = Tb Else Crr(Z(Tb & "/Ra") - 1, 2) = Crr(Z(Tb & "/Ra") - 1, 2) + 1
   If Tb <> "" Then Z(Tb) = Z(Tb) + 1: Z(Tb & "/Rb") = i: Brr(i, 6) = ""
Next
For Each K In Z.KEYS
   If InStr(K, "/") = 0 And Z(K) = 2 Then N = N + 1: Arr(Z(K & "/Ra"), 6) = N: Brr(Z(K & "/Rb"), 6) = N
Next
Application.Goto [比對結果!A1]
ActiveSheet.UsedRange.Clear: [A:B,H:H].NumberFormatLocal = "@"
With [A2].Resize(R, 2): .Value = Crr: .Sort KEY1:=.Item(2), Order1:=2, Header:=1: [A1] = "NUMBER": End With
With [B1].Resize(UBound(Arr), 6): .Value = Arr: .Sort KEY1:=.Item(6), Order1:=1, Header:=1: Arr = .Value: End With
With [H1].Resize(UBound(Brr), 6): .Value = Brr: .Sort KEY1:=.Item(6), Order1:=1, Header:=1: Brr = .Value: End With
[G:G,M:M].ClearContents: Set xR = ActiveSheet.UsedRange.Offset(N + 1, 1)
For i = 2 To N + 1
   For j = 3 To 6: Set xR = IIf(Val(Arr(i, j)) <> Val(Brr(i, j)), Union(xR, Cells(i, j + 1)), xR): Next
Next
Intersect(Union(xR, xR.Offset(, 6)), ActiveSheet.UsedRange).Font.ColorIndex = 3
With Sheets("留下相同")
   .UsedRange.Clear: ActiveSheet.UsedRange.Copy .[A1]: .Range(Intersect(xR, ActiveSheet.UsedRange).Address).EntireRow.Delete
End With
With Sheets("留下差異")
   .UsedRange.Clear: Intersect(Union([A1], xR), ActiveSheet.UsedRange).EntireRow.Copy .[A1]
End With
End Sub
用行動裝置瀏覽論壇學習很方便,謝謝論壇經營團隊
請大家一起上論壇來交流

TOP

回復 2# Andy2483
謝謝您的教導
如果我比對資料欄數不固定
比對結果A欄想呈現所有資料,差異標紅色新增標藍色
如何做?



Excel比對資料.rar (20.86 KB)

TOP

回復 3# aassddff736

以下是欄數不固定,以原排序方式的方案,請前輩參考
Option Explicit
Sub TEST1()
Dim Arr, Brr, Crr, C%, K, Z, N&, i&, j%, R&, Ta$, Tb$, xR As Range
Set Z = CreateObject("Scripting.Dictionary")
Set Arr = Sheets(1).[A1].CurrentRegion: Arr = Union(Arr, Arr.Offset(, 1)): Set Brr = Sheets(2).[A1].CurrentRegion: Brr = Union(Brr, Brr.Offset(, 1))
C = UBound(Arr, 2): If C <> UBound(Brr, 2) Then Exit Sub
ReDim Crr(1 To (UBound(Arr) + UBound(Brr)), 1 To 2)
For i = 1 To UBound(Arr)
   Ta = Trim(Arr(i, 1)): If Ta <> "" Then Z(Ta) = Z(Ta) + 1: Z(Ta & "/Ra") = i: R = R + 1: Crr(R, 1) = Ta: Crr(R, 2) = 1
Next
For i = 1 To UBound(Brr)
   Tb = Trim(Brr(i, 1)): If Z(Tb) = 0 Then R = R + 1: Crr(R, 1) = Tb Else Crr(Z(Tb & "/Ra"), 2) = Crr(Z(Tb & "/Ra"), 2) + 1
   If Tb <> "" Then Z(Tb) = Z(Tb) + 1: Z(Tb & "/Rb") = i
Next
For Each K In Z.KEYS
   If InStr(K, "/") = 0 And Z(K) = 2 Then N = N + 1: Arr(Z(K & "/Ra"), C) = N: Brr(Z(K & "/Rb"), C) = N
Next
Application.Goto [比對結果!A1]
ActiveSheet.UsedRange.Clear: [A1] = "NUMBER"
With [A2].Resize(R, 2): .Value = Crr: .Sort KEY1:=.Item(2), Order1:=2, Header:=1: .Columns(2).ClearContents: End With
With [B2].Resize(UBound(Arr), C): .Value = Arr: .Sort KEY1:=.Item(C), Order1:=1, Header:=1: Arr = .Value: .Columns(C).ClearContents: End With
With Cells(2, C + 2).Resize(UBound(Brr), C): .Value = Brr: .Sort KEY1:=.Item(C), Order1:=1, Header:=1: Brr = .Value: .Columns(C).ClearContents: End With
[B1] = "New": [B1].Resize(, C - 1).Merge: [B1].Item(, C + 1) = "Old": [B1].Item(, C + 1).Resize(, C - 1).Merge
Set xR = ActiveSheet.UsedRange.Offset(N + 1, 1)
For i = 1 To N
   For j = 3 To C: Set xR = IIf(Val(Arr(i, j)) <> Val(Brr(i, j)), Union(xR, Cells(i + 1, j + 1), Cells(i + 1, 2)), xR): Next
Next
Intersect(Union(xR, xR.Offset(, C)), ActiveSheet.UsedRange).Font.ColorIndex = 3
With Sheets("留下相同")
   .UsedRange.Clear: ActiveSheet.UsedRange.Copy .[A1]:   .Range(Intersect(xR.EntireRow, ActiveSheet.UsedRange).Address).EntireRow.Delete
End With
With Sheets("留下差異")
   .UsedRange.Clear: Intersect(Union([A1], xR.EntireRow), ActiveSheet.UsedRange).EntireRow.Copy .[A1]
End With
End Sub
用行動裝置瀏覽論壇學習很方便,謝謝論壇經營團隊
請大家一起上論壇來交流

TOP

回復 4# Andy2483


  感謝大神指教
這個好像是同列比對我想要的是只要資料相同是為一樣不管順序
比對結果A,B,J欄位置要一樣

TOP

回復 4# Andy2483


    ★座標比對顏色調整.zip (58.17 KB)
能幫我看看這個檔案
我想要增加一頁只秀差異部分 比對結果new,old 間留一行空白比較沒這麼亂

TOP

本帖最後由 Andy2483 於 2024-2-16 14:52 編輯

回復 5# aassddff736

比對結果A,B,J欄位置一樣的方案,請前輩參考

Option Explicit
Sub TEST2()
Dim Arr, Brr, Crr, C%, Z, N&, i&, j%, R&, Ta$, Tb$, xR As Range, xB As Range, xS As Worksheet
Set Z = CreateObject("Scripting.Dictionary"): Set xS = Sheets("比對結果")
Set Arr = Sheets(1).[A1].CurrentRegion: Arr = Union(Arr, Arr.Offset(, 1))
Set Brr = Sheets(2).[A1].CurrentRegion: Brr = Union(Brr, Brr.Offset(, 1))
C = UBound(Arr, 2): If C <> UBound(Brr, 2) Then MsgBox "欄數不同": Exit Sub
ReDim Crr(1 To (UBound(Arr) + UBound(Brr)), 1 To C * 2 + 1)
For i = 1 To UBound(Arr)
   Ta = Trim(Arr(i, 1)): R = R + 1: Z(Ta) = R: Crr(R, 1) = Ta
   For j = 1 To C: Crr(R, j + 1) = Arr(i, j): Next
Next
For i = 1 To UBound(Brr)
   Tb = Trim(Brr(i, 1)): N = Z(Tb): If N = 0 Then R = R + 1: Crr(R, 1) = Tb: N = R: Z(Tb) = R
   For j = 1 To C: Crr(N, j + 1 + C) = Brr(i, j): Next
Next
Application.Goto xS.[A1]
xS.UsedRange.Clear: [A1] = "NUMBER"
With [A2].Resize(R, C * 2 + 1): .Value = Crr: .Sort KEY1:=.Item(2), Order1:=1, Header:=2: Crr = .Value: End With
[B1] = "New": [B1].Resize(, C - 1).Merge: [B1].Item(, C + 1) = "Old": [B1].Item(, C + 1).Resize(, C - 1).Merge
Set xR = xS.UsedRange: Set xR = xR(xR.Count + 1): Set xB = xR
For i = 2 To R + 1
   For j = 3 To C
      Set xR = IIf(Crr(i - 1, j) <> Crr(i - 1, j + C), Union(xR, Cells(i, j), Cells(i, 1)), xR)
      If Crr(i - 1, j) = "" Or Crr(i - 1, j + C) = "" Then Set xB = Union(xB, Cells(i, j))
   Next
Next
Union(xR, xR.Offset(, C)).Font.ColorIndex = 3
xB.EntireRow.Font.ColorIndex = 5
With Sheets("留下相同")
   .UsedRange.Clear: xS.UsedRange.Copy .[A1]
   .Range(Intersect(xR.EntireRow, xS.UsedRange).Address).EntireRow.Delete
End With
With Sheets("留下差異")
   .UsedRange.Clear: Intersect(Union([A1], xR.EntireRow), xS.UsedRange).EntireRow.Copy .[A1]
End With
End Sub
用行動裝置瀏覽論壇學習很方便,謝謝論壇經營團隊
請大家一起上論壇來交流

TOP

回復 6# aassddff736

只秀差異部分 比對結果new,old 間留一行空白 方案如下,請前輩參考
Option Explicit
Sub TEST2()
Dim Arr, Brr, Crr, C%, Z, N&, i&, j%, R&, Ta$, Tb$, xR As Range, xB As Range, xS As Worksheet
Set Z = CreateObject("Scripting.Dictionary"): Set xS = Sheets("Result")
Set Arr = Sheets(2).[A1].CurrentRegion: Arr = Union(Arr, Arr.Offset(, 1))
Set Brr = Sheets(3).[A1].CurrentRegion: Brr = Union(Brr, Brr.Offset(, 1))
C = UBound(Arr, 2): If C <> UBound(Brr, 2) Then MsgBox "欄數不同": Exit Sub
ReDim Crr(1 To (UBound(Arr) + UBound(Brr)), 1 To C * 2 + 1)
For i = 1 To UBound(Arr)
   Ta = Trim(Arr(i, 1)): R = R + 1: Z(Ta) = R: Crr(R, 1) = Ta
   For j = 1 To C: Crr(R, j + 1) = Arr(i, j): Next
Next
For i = 1 To UBound(Brr)
   Tb = Trim(Brr(i, 1)): N = Z(Tb): If N = 0 Then R = R + 1: Crr(R, 1) = Tb: N = R: Z(Tb) = R
   For j = 1 To C: Crr(N, j + 1 + C) = Brr(i, j): Next
Next
Application.Goto xS.[A1]
xS.UsedRange.Clear: [A1] = "NUMBER"
With [A2].Resize(R, C * 2 + 1): .Value = Crr: .Sort KEY1:=.Item(2), Order1:=1, Header:=1: Crr = .Value: End With
[B1] = "New": [B1].Resize(, C - 1).Merge: [B1].Item(, C + 1) = "Old": [B1].Item(, C + 1).Resize(, C - 1).Merge
Set xR = xS.UsedRange: Set xR = xR(xR.Count + 1): Set xB = xR
For i = 2 To R + 1
   For j = 3 To C
      Set xR = IIf(Crr(i - 1, j) <> Crr(i - 1, j + C), Union(xR, Cells(i, j), Cells(i, 1)), xR)
      If Crr(i - 1, j) = "" Or Crr(i - 1, j + C) = "" Then Set xB = Union(xB, Cells(i, j))
   Next
Next
Union(xR, xR.Offset(, C)).Font.ColorIndex = 3
xB.EntireRow.Font.ColorIndex = 5
End Sub
用行動裝置瀏覽論壇學習很方便,謝謝論壇經營團隊
請大家一起上論壇來交流

TOP

回復 7# Andy2483


可以了也 謝謝大神
能依照A欄排序嗎?

TOP

回復 9# aassddff736


    .Sort KEY1:=.Item(2) 改為 .Sort KEY1:=.Item(1)
用行動裝置瀏覽論壇學習很方便,謝謝論壇經營團隊
請大家一起上論壇來交流

TOP

        靜思自在 : 忘功不忘過,忘怨不忘恩。
返回列表 上一主題