|
Private Sub CommandButton1_Click()
With ListBox1
For i = 0 To .ListCount - 1
.Selected(i) = True
Next i
End With
End Sub
Private Sub CommandButton2_Click()
With ListBox1
For i = 0 To .ListCount - 1
.Selected(i) = False
Next i
End With
End Sub
Private Sub CommandButton3_Click()
With ListBox1
For i = 0 To .ListCount - 1
If .Selected(i) = True Then
.Selected(i) = False
Else
.Selected(i) = True
End If
Next i
End With
End Sub
Private Sub CommandButton4_Click()
Dim ar As Variant, br As Variant
Dim rn As Range
Dim i As Long, r As Long, yy As Long
Dim d As Object, dc As Object
Dim rr()
ReDim rr(1 To ListBox1.ListCount)
Set d = CreateObject("scripting.dictionary")
Set dc = CreateObject("scripting.dictionary")
Set dic = CreateObject("scripting.dictionary")
With ActiveSheet
r = .Cells(Rows.Count, 1).End(xlUp).Row
yy = .Cells(3, Columns.Count).End(xlToLeft).Column
zd = Trim(.[b1])
If r > 3 Then .Range(.Cells(4, 1), .Cells(r, yy)).Clear
br = .Range(.Cells(3, 1), .Cells(50000, yy))
For j = 2 To UBound(br, 2)
If Trim(br(1, j)) <> "" Then
d(Trim(br(1, j))) = j
End If
Next j
With ListBox1
For i = 0 To .ListCount - 1
If .Selected(i) = True Then
n = n + 1
dic(.List(i, 0)) = ""
End If
Next i
End With
If n = "" Then MsgBox "请选择要汇总的单号!": Exit Sub
k = 1
For Each sh In Sheets
If sh.Name <> "求和" Then
ar = sh.[a1].CurrentRegion
Set rn = sh.Rows(1).Find("生产任务单号", , , , , , 1)
If rn Is Nothing Then MsgBox sh.Name & "中没有生产任务单号字段!": End
y = rn.Column
For i = 2 To UBound(ar)
If Trim(ar(i, y)) <> "" Then
If dic.exists(Trim(ar(i, y))) Then
T = dc(Trim(ar(i, y)))
If T = "" Then
k = k + 1
dc(Trim(ar(i, y))) = k
T = k
br(k, 1) = ar(i, y)
End If
For j = 1 To UBound(ar, 2)
lh = d(Trim(ar(1, j)))
If lh <> "" Then
br(T, lh) = br(T, lh) + ar(i, j)
End If
Next j
End If
End If
Next i
End If
Next sh
If k = 1 Then MsgBox "没有符合具体的数据!": End
.[a3].Resize(k, UBound(br, 2)) = br
End With
MsgBox "ok!"
End Sub
Private Sub UserForm_Initialize()
Dim ar As Variant
Dim rn As Range
Dim i As Long
Dim d As Object
Set dic = CreateObject("scripting.dictionary")
For Each sh In Sheets
If sh.Name <> "求和" Then
Set rn = sh.Rows(1).Find("生产任务单号", , , , , , 1)
If rn Is Nothing Then MsgBox sh.Name & "中没有生产任务单号字段!": End
y = rn.Column
ar = sh.[a1].CurrentRegion
For i = 2 To UBound(ar)
If Trim(ar(i, y)) <> "" Then
dic(Trim(ar(i, y))) = ""
End If
Next i
Set rn = Nothing
End If
Next sh
Me.ListBox1.List = dic.keys
Set dic = Nothing
End Sub
|
|