- Sub test()
- Dim r%, i%
- Dim arr, brr(1 To 2, 35 To 36) As Double
- Dim d As Object
- Set d = CreateObject("scripting.dictionary")
- With Worksheets(1)
- r = .Cells(.Rows.Count, "aa").End(xlUp).Row
- i = 4
- Do Until .Cells(i, 31) <> "期初余额"
- i = i + 1
- Loop
- For j = 35 To 36
- brr(1, j) = Val(.Cells(i, j))
- brr(2, j) = Val(.Cells(i, j))
- Next
- i = i + 1
- Do While .Cells(i, 33) <> ""
- If .Cells(i, 34) = .Cells(i - 1, 34) Then
- If .Cells(i, 27) = .Cells(i - 1, 27) Then
- For j = 35 To 36
- brr(1, j) = brr(1, j) + Val(.Cells(i, j))
- Next
- Else
- .Rows(i).Insert shift:=xlDown
- .Cells(i, 31) = "本月合计"
- .Cells(i, 34) = .Cells(i - 1, 34)
- .Cells(i, 35).Resize(1, 2) = Application.Index(brr, 1, 0)
- .Rows(i + 1).Insert shift:=xlDown
- .Cells(i + 1, 31) = "本年累计"
- .Cells(i + 1, 34) = .Cells(i - 1, 34)
- .Cells(i + 1, 35).Resize(1, 2) = Application.Index(brr, 2, 0)
- For j = 35 To 36
- brr(1, j) = Val(.Cells(i + 2, j))
- Next
- i = i + 2
- End If
- For j = 35 To 36
- brr(2, j) = brr(2, j) + Val(.Cells(i, j))
- Next
- Else
- .Rows(i).Insert shift:=xlDown
- .Cells(i, 31) = "本月合计"
- .Cells(i, 34) = .Cells(i - 1, 34)
- .Cells(i, 35).Resize(1, 2) = Application.Index(brr, 1, 0)
- .Rows(i + 1).Insert shift:=xlDown
- .Cells(i + 1, 31) = "本年累计"
- .Cells(i + 1, 34) = .Cells(i - 1, 34)
- .Cells(i + 1, 35).Resize(1, 2) = Application.Index(brr, 2, 0)
- For k = 1 To 2
- For j = 35 To 36
- brr(k, j) = Val(.Cells(i + 2, j))
- Next
- Next
- i = i + 2
- End If
- i = i + 1
- Loop
- .Cells(i, 31) = "本月合计"
- .Cells(i, 34) = .Cells(i - 1, 34)
- .Cells(i, 35).Resize(1, 2) = Application.Index(brr, 1, 0)
- .Cells(i + 1, 31) = "本年累计"
- .Cells(i + 1, 34) = .Cells(i - 1, 34)
- .Cells(i + 1, 35).Resize(1, 2) = Application.Index(brr, 2, 0)
- End With
- End Sub
复制代码 |