|
本帖最后由 ykcbf1100 于 2024-4-17 09:36 编辑
参与一下。。。
- Sub ykcbf() '//2024.4.17
- Dim arr, brr, d, s
- Application.ScreenUpdating = False
- Application.DisplayAlerts = False
- Set d = CreateObject("scripting.dictionary")
- Set sh = ThisWorkbook.Sheets("汇总")
- ReDim brr(1 To 10000, 1 To 300)
- m = 2: n = 3: bt = 2
- On Error Resume Next
- For Each Sht In Sheets
- If Sht.Name <> sh.Name Then
- k = k + 1
- With Sht
- r = .Cells(Rows.Count, 1).End(3).Row
- c = .UsedRange.Columns.Count
- arr = .Range("a1").Resize(r, c)
- If k = 1 Then
- brr(1, 1) = arr(2, 1): brr(1, 2) = arr(2, 2): brr(1, 3) = arr(2, 3)
- End If
- For i = bt + 1 To UBound(arr)
- If arr(i, 1) <> Empty Then
- s = CStr(arr(i, 2))
- If Not d.exists(s) Then
- m = m + 1
- d(s) = m
- brr(m, 1) = m - 2
- brr(m, 2) = s
- brr(m, 3) = arr(i, 3)
- End If
- r = d(arr(i, 2))
- For j = 4 To UBound(arr, 2) Step 6
- For x = 1 To 2
- s = arr(1, j) & "|" & arr(2, j + x)
- If Not d.exists(s) Then
- n = n + 1
- d(s) = n
- brr(1, n) = Format(arr(1, j), "yyyy年m月")
- brr(2, n) = arr(2, j + x)
- End If
- c = d(arr(1, j) & "|" & arr(2, j + x))
- brr(r, c) = arr(i, j + x)
- Next
- Next
- End If
- Next
- End With
- End If
- Next
- With sh
- .UsedRange.Clear
- .Columns(2).NumberFormatLocal = "@"
- .[a1].Resize(m, n - 1) = brr
- .[a1].Resize(2, n - 1).Interior.Color = 49407
- .[a3].Resize(m - 2, 1).Interior.Color = 5296274
- For j = 1 To 3
- .Cells(1, j).Resize(2).Merge
- Next
- For j = 4 To n Step 2
- .Cells(1, j).Resize(1, 2).Merge
- Next
- ActiveWindow.DisplayZeros = False
- Set Rng = .[a1].Resize(m, n - 1)
- With Rng
- .Borders.LineStyle = 1
- .HorizontalAlignment = xlCenter
- .VerticalAlignment = xlCenter
- .Columns.AutoFit
- With .Font
- .Name = "微软雅黑"
- .Size = 11
- End With
- End With
- End With
- Set d = Nothing
- MsgBox "OK!"
- End Sub
复制代码
|
评分
-
3
查看全部评分
-
|