|
[广告] Excel易用宝 - 提升Excel的操作效率 · Excel / WPS表格插件 ★ 免费下载 ★ ★ 使用帮助★
工作中做的一个功能,可以汇总显示相同产品对应数量,只是代码写的不好,分享一下给大家,看看有没有更好的写法。
代码如下:
- Private Sub CommandButton2_Click() ' 汇总
- Dim r, i, j, h, M As Long
- Dim Rng As Variant
-
- r = Worksheets("汇总表").Range("C65536").End(xlUp).Row
- Rng = Worksheets("汇总表").Range("A1:I" & r).Value
-
- '------------------------------------------------------------------------按 仓位、货品编码 排序
- Application.ScreenUpdating = True
- Range("A2:I" & r).Sort Key1:=Range("D2"), Order1:=xlAscending, Key2:=Range("E2") _
- , Order2:=xlAscending, Key3:=Range("G2"), Order3:=xlAscending, Header:=xlNo, OrderCustom:=1, MatchCase:=True _
- , Orientation:=xlTopToBottom, SortMethod:=xlPinYin, DataOption1:= _
- xlSortNormal, DataOption2:=xlSortNormal
- '------------------------------------------------------------------------按 货品名 对 大于1的数量求和
- r = Worksheets("汇总表").Range("C65536").End(xlUp).Row
- Rng = Worksheets("汇总表").Range("A1:I" & r).Value
-
- M = 2
- f: For i = M To r
- If Rng(i - 1, 5) = Rng(i, 5) And Rng(i, 7) >= 1 And Rng(i - 1, 8) = "□" Then '商品编码 与上一行相同, 且 数量大于等于1 ,且 上一行 核对列 为"□" (核对列 除了数量是小数外,全部是"□")
- h = 2
-
- For j = i + 1 To r '查询有多少相同的行
- If Rng(i, 5) = Rng(j, 5) And Rng(j, 7) >= 1 Then 'rng(j,7) 第7列是数量
- h = h + 1 '累计行数
- End If
- Next
-
-
- If h = 2 Then '两行相同 的商品编码
- If ((Rng(i - 1, 7) + Rng(i, 7))) < 10 Then
- Range("H" & i - 1) = "╮ "
- Range("H" & i) = "╯" & (Rng(i - 1, 7) + Rng(i, 7)) & " " '1位数字,多加个空格,看起来整齐。
- Else
- Range("H" & i - 1) = "╮ "
- Range("H" & i) = "╯" & (Rng(i - 1, 7) + Rng(i, 7))
- End If
- ElseIf h = 3 Then '三行相同 的商品编码
- Range("H" & i - 1) = "─╮"
- Range("H" & i) = Rng(i - 1, 7) + Rng(i, 7) + Rng(i + 1, 7) '奇数行 中间行汇总数量
- Range("H" & i + 1) = "─╯"
- ElseIf h = 4 Then
- Range("H" & i - 1) = "─╮"
- Range("H" & i) = "│"
- Range("H" & i + 1) = Rng(i - 1, 7) + Rng(i, 7) + Rng(i + 1, 7) + Rng(i + 2, 7) '偶数行 偏下一行汇总数量
- Range("H" & i + 2) = "─╯"
- ElseIf h = 5 Then
- Range("H" & i - 1) = "─╮"
- Range("H" & i) = "│"
- Range("H" & i + 1) = Rng(i - 1, 7) + Rng(i, 7) + Rng(i + 1, 7) + Rng(i + 2, 7) + Rng(i + 3, 7)
- Range("H" & i + 2) = "│"
- Range("H" & i + 3) = "─╯"
- '这里只汇总5行 相同的货品,附件中代码写了汇总17行
- End If
- M = i + h
- GoTo f
- End If
- Next
- Range("F2:H" & r).Select '选择 需要打印的 区域
- Application.ScreenUpdating = False
- '------------------------------------------------------------------------打印 汇总
- If MsgBox("要先【打印】此汇总单吗?", vbQuestion + vbYesNo, "打印提示") = vbYes Then
- ActiveSheet.PageSetup.PrintArea = ActiveSheet.Range("F2:H" & r).Address '设置选择区域 为打印区域
- ActiveSheet.PrintOut Copies:=1, Collate:=True
- End If
- End Sub
- Private Sub CommandButton15_Click() '按单号 排序
- Dim r, i As Long
- Dim Rng As Variant
-
- '-----------------------------------------------------------------------查询
- r = Worksheets("汇总表").Range("C65536").End(xlUp).Row
- Rng = Worksheets("汇总表").Range("A1:I" & r).Value
-
- Application.ScreenUpdating = False
-
- With ActiveSheet
- For i = 2 To r
- If Rng(i, 7) >= 1 Then
- .Cells(i, 8) = "□" '核对列设置 勾选框
- Else
- .Cells(i, 8) = "***" '数量是小数 另设置其他符号
- End If
- Next
- End With
- '-----------------------------------------------------------------------排序
- ActiveSheet.Range("A1:I1000").Select
- Selection.Sort Key1:=Range("A1"), Order1:=xlAscending, Header:=xlYes, OrderCustom:=1, MatchCase:=True _
- , Orientation:=xlTopToBottom, SortMethod:=xlPinYin, DataOption1:= _
- xlSortNormal, DataOption2:=xlSortNormal
- Range("A2").Select
-
- Application.ScreenUpdating = True
- End Sub
复制代码
附件是建好的一个测试文档。
明了的数量汇总显示.rar
(26.82 KB, 下载次数: 26)
补充内容 (2018-7-27 18:42):
11楼有升级版
http://club.excelhome.net/thread-1343883-2-1.html |
|