標題:
如何將同檔案中兩sheet作比較,再將比較結果另存其他sheet中?
[打印本頁]
作者:
ckl520
時間:
2012-5-24 15:18
標題:
如何將同檔案中兩sheet作比較,再將比較結果另存其他sheet中?
vba小嫩咖遇到問題,需要將同檔案中兩sheet作比較,再將比較結果
另存其他sheet中。如下所敘,懇請各位高手大大幫忙。
thanks~
如何比對sheet2 & Sheet3資料,並將比對結果
存於其他sheet中
1.兩者都有-->sheet4
2.sheet2有,sheet3沒有-->Sheet5
3.Sheet3有,sheet2沒有-->Sheet6
shee2 資料如圖fig.1
sheet3 資料如圖fig.2
作者:
register313
時間:
2012-5-24 18:51
回復
1#
ckl520
設sheet2~sheet6 之A欄為P/N , B欄為Location
Sub XX()
Dim d1 As Object, d2 As Object, A As Range
Dim Ar, Br()
Set d1 = CreateObject("Scripting.Dictionary")
Set d2 = CreateObject("Scripting.Dictionary")
With Sheet2
For Each A In .Range("A2:A" & .[A2].End(xlDown).Row)
d1.Add A.Value, A.Offset(0, 1).Value
Next
End With
With Sheet3
For Each A In .Range("A2:A" & .[A2].End(xlDown).Row)
d2.Add A.Value, A.Offset(0, 1).Value
Next
End With
S = 1
Ar = d1.keys
ReDim Preserve Br(1 To d1.Count + d2.Count, 1 To 2)
For I = LBound(Ar) To UBound(Ar)
If d2.Exists(Ar(I)) Then
Br(S, 1) = Ar(I): Br(S, 2) = d1(Ar(I)): d1.Remove (Ar(I)): S = S + 1
Br(S, 1) = Ar(I): Br(S, 2) = d2(Ar(I)): d2.Remove (Ar(I)): S = S + 1
End If
Next I
For I = 4 To 6
Sheets(I).[A:B] = ""
Sheets(I).[A1:B1] = Array("P/N", "Location")
Next I
Sheet4.[A2].Resize(UBound(Br, 1), 2) = Br
Sheet5.[A2].Resize(d1.Count, 1) = Application.Transpose(d1.keys)
Sheet5.[B2].Resize(d1.Count, 1) = Application.Transpose(d1.items)
Sheet6.[A2].Resize(d2.Count, 1) = Application.Transpose(d2.keys)
Sheet6.[B2].Resize(d2.Count, 1) = Application.Transpose(d2.items)
End Sub
複製代碼
作者:
ckl520
時間:
2012-6-1 15:09
register313 大大 你好:
1.套用後,程式會卡在這行 Sheet4.[A2].Resize(UBound(Br, 1), 2) = Br
2.已查過網上資料,但還是看不太懂,無法排障。能煩請大大分段解釋程式意思。
再次感謝高手幫忙。
thanks~
作者:
register313
時間:
2012-6-1 16:02
回復
3#
ckl520
請上傳excel壓縮檔
作者:
ckl520
時間:
2012-6-1 17:46
TO:register313
http://www.badongo.com/file/27212832
thanks~
作者:
register313
時間:
2012-6-1 19:00
回復
5#
ckl520
1.工作表code name 改為 name
2.修正 sheet4~sheet6 A欄 會變為日期格式之問題
Private Sub CommandButton1_Click()
Dim d1 As Object, d2 As Object, A As Range
Dim Ar, Br() As String, Cr
Set d1 = CreateObject("Scripting.Dictionary")
Set d2 = CreateObject("Scripting.Dictionary")
With Sheets("Sheet2")
For Each A In .Range("A2:A" & .[A2].End(xlDown).Row)
d1.Add A.Value, A.Offset(0, 1).Value
Next
End With
With Sheets("Sheet3")
For Each A In .Range("A2:A" & .[A2].End(xlDown).Row)
d2.Add A.Value, A.Offset(0, 1).Value
Next
End With
S = 1
Ar = d1.keys
ReDim Preserve Br(1 To d1.Count + d2.Count, 1 To 2)
For I = LBound(Ar) To UBound(Ar)
If d2.Exists(Ar(I)) Then
Br(S, 1) = Ar(I): Br(S, 2) = d1(Ar(I)): d1.Remove (Ar(I)): S = S + 1
d2.Remove (Ar(I)): S = S + 1
End If
Next I
For I = 4 To 6
Sheets("Sheet" & I & "").[A:B] = ""
Sheets("Sheet" & I & "").[A1:B1] = Array("P/N", "Location")
Sheets("Sheet" & I & "").[A:B].NumberFormatLocal = "@"
Next I
Sheets("Sheet4").[A2].Resize(UBound(Br, 1), 2) = Br
Sheets("Sheet5").[A2].Resize(d1.Count, 1) = Application.Transpose(d1.keys)
Sheets("Sheet5").[B2].Resize(d1.Count, 1) = Application.Transpose(d1.items)
Sheets("Sheet6").[A2].Resize(d2.Count, 1) = Application.Transpose(d2.keys)
Sheets("Sheet6").[B2].Resize(d2.Count, 1) = Application.Transpose(d2.items)
End Sub
複製代碼
作者:
ckl520
時間:
2012-6-4 17:43
謝謝register313 大大
可以work了!
歡迎光臨 麻辣家族討論版版 (http://forum.twbts.com/)