|
本帖最后由 dsmch 于 2013-5-2 22:08 编辑
- Sub Macro1()
- Dim arr, brr, crr, d As Object, i&, j&
- Set d = CreateObject("scripting.dictionary")
- arr = Range("a1").CurrentRegion '原始数据
- brr = Range("a15").CurrentRegion '目标数据
- ReDim crr(1 To UBound(brr) - 1, 1 To UBound(brr, 2) - 1)
- For i = 2 To UBound(arr)
- Set d(arr(i, 1)) = CreateObject("scripting.dictionary") '设置字典嵌套
- Next
- For i = 2 To UBound(arr)
- For j = 2 To UBound(arr, 2)
- d(arr(i, 1))(arr(1, j)) = d(arr(i, 1))(arr(1, j)) + arr(i, j)
- Next
- Next
- For i = 2 To UBound(brr)
- For j = 2 To UBound(brr, 2)
- crr(i - 1, j - 1) = d(brr(i, 1))(brr(1, j))
- Next
- Next
- Range("b16").Resize(UBound(crr), UBound(crr, 2)) = crr
- End Sub
复制代码 通常字典是一对一对应,在一对多的情况下,先用符号连接,然后用split分割,字典嵌套能很好地解决这类问题,详细见附件
|
评分
-
4
查看全部评分
-
|