Sub NewWorkBooks()
Dim d As Object, arr, brr, r, kr, i&, j&, k&, x&, Mystr$
Dim Rng As Range, Rg As Range, tRow&, tCol&, aCol&, pd&, mypath$
Dim Cll As Range, sht As Worksheet
‘ ‘
‘第一部分,用户选择保存分表工作簿的路径。
With Application.FileDialog(msoFileDialogFolderPicker)
‘选择保存工作薄的文件路径
.AllowMultiSelect = False
‘不允许多选
If .Show Then
mypath = .SelectedItems(1)
‘读取选择的文件路径
Else
Exit Sub
‘如果没有选择保存路径,则退出程序
End If
End With
If Right(mypath, 1) <> “\” Then mypath = mypath & “\”
‘ ‘
‘第二部分遍历总表数据,通过字典将指定字段的不同明细行过滤保存
Set d = CreateObject(“scripting.dictionary”) ‘set字典
Set Rg = Application.InputBox(“请框选拆分依据列!只能选择单列单元格区域!”, Title:=”提示”, Type:=8)
‘用户选择的拆分依据列
tCol = Rg.Column ‘取拆分依据列列标
tRow = Val(Application.InputBox(“请输入总表标题行的行数?”))
‘用户设置总表的标题行数
If tRow < 0 Then MsgBox “标题行数不能为负数,程序退出。”: Exit Sub
Set Rng = ActiveSheet.UsedRange ‘总表的数据区域
Set Cll = ActiveSheet.Cells ‘用于在分表粘贴和总表同样行高列宽的数据格式
arr = Rng ‘数据范围装入数组arr
tCol = tCol – Rng.Column + 1 ‘计算依据列在数组中的位置
aCol = UBound(arr, 2) ‘数据源的列数
For i = tRow + 1 To UBound(arr) ‘遍历数组arr
If arr(i, tCol) = “” Then arr(i, tCol) = “单元格空白”
Mystr = arr(i, tCol) ‘统一转换为字符串格式
If Not d.exists(Mystr) Then
d(Mystr) = i ‘字典中不存在关键词则将行号装入字典
Else
d(Mystr) = d(Mystr) & “,” & i ‘如果存在则合并行号,以逗号间隔
End If
Next
‘ ‘
‘第三部分遍历字典取出分表数据明细,建立不同工作簿保存数据。
Application.ScreenUpdating = False ‘关闭屏幕刷新
Application.DisplayAlerts = False ‘关闭系统警告信息
kr = d.keys ‘字典的key集
For i = 0 To UBound(kr) ‘遍历字典key值
If kr(i) <> “” Then ‘如果key不为空
r = Split(d(kr(i)), “,”) ‘取出item里储存的行号
ReDim brr(1 To UBound(r) + 1, 1 To aCol) ‘声明放置结果的数组brr
k = 0
For x = 0 To UBound(r)
k = k + 1‘累加记录行数
For j = 1 To aCol ‘遍历读取列
brr(k, j) = arr(r(x), j)
Next
Next
With Workbooks.Add
‘新建一个工作簿
With .Sheets(1).[a1]
Cll.Copy ‘复制粘贴总表的单元格格式
.PasteSpecial Paste:=xlPasteFormats, Operation:=xlNone, SkipBlanks:=False, Transpose:=False
Cells.NumberFormat = “@” ‘设置文本格式,防止文本值变形
If tRow > 0 Then .Resize(tRow, aCol) = arr ‘放标题行
.Offset(tRow, 0).Resize(k, aCol) = brr ‘放置数据区域
.Select‘激活A1单元格
End With
.SaveAs mypath & kr(i), xlWorkbookDefault ‘保存工作簿
.Close True ‘关闭工作簿
End With
End If
Next
‘收尾巴。
Set d = Nothing ‘释放字典
Erase arr: Erase brr ‘释放数组
MsgBox “处理完成。”, , “提醒”
Application.ScreenUpdating = True ‘恢复屏幕刷新
Application.DisplayAlerts = True ‘恢复显示系统警告和消息
End Sub