|
本帖最后由 sunya_0529 于 2014-10-17 11:00 编辑
征途2 发表于 2014-10-16 20:28
我可不可以同时建立多个这样的设置,例如求调休合计数,休息合计数,事假合计数,请问如何设置啊,能否帮 ...
把上面的自定义函数稍微修改一下,增加一个可选参数,如果填“事假”、“调休”、“休息”中的任意一个,则会单独计算对应的数值,不填则默认求和,效果如下所示——
自定义函数的代码更新如下——
- Function MSUM(rng As Range, Optional flag As String) As Single
- On Error Resume Next
- Dim c As Range, str$, arr, i%, x!, y!
- If Not rng Is Nothing Then
- For Each c In rng
- str = Replace(c.Value, " ", Chr(10))
- arr = Split(str, Chr(10))
- For i = 0 To UBound(arr)
- If Len(flag) > 0 And InStr(arr(i), flag) > 0 Then x = x + CSng(Replace(arr(i), flag, ""))
- y = y + CSng(Replace(Replace(Replace(arr(i), "休息", "-"), "调休", "-"), "事假", "-"))
- Next i
- Next c
- MSUM = IIf(Len(flag) > 0, x, y)
- End If
- End Function
复制代码
|
|