|
楼主 |
发表于 2019-9-9 13:09
|
显示全部楼层
[广告] VBA代码宝 - VBA编程加强工具 · VBA代码随查随用 · 内置多项VBA编程加强工具 ★ 免费下载 ★ ★ 使用手册★
本帖最后由 YZC51 于 2019-9-9 19:01 编辑
'具有 Split 功能的自定义函数
Function Split(ByVal rng As String, Optional ByVal yrng As String = " ", Optional ByVal num As Integer = 0) As String
rng = rng & yrng
If num < 0 Then Split = "": Exit Function
Select Case num
Case 0
If InStr(rng, yrng) = 0 Then Split = "": Exit Function
Split = Mid(rng, 1, InStr(rng, yrng) - 1)
Case Else
rng1 = Replace(rng, yrng, "", , num - 1)
If InStr(rng1, yrng) < 1 Then Split = "": Exit Function
Split = Mid(rng1, InStr(rng1, yrng) + Len(yrng))
End Select
End Function
'加强型 Split 功能的自定义函数
Function Splity(rng, Optional y = " ", Optional n = 0, Optional m = 0)
'y=默认分隔符为空格
'n=从第几节开始取,n为0时全取
'm=共取几节
rng = rng & y
If n < 0 Then Splity = "": Exit Function
If n = 0 Then
Splity = rng
Else
rng1 = Replace(rng, y, "", , n - 1)
Splity = Mid(rng1, InStr(rng1, y) + Len(y))
End If
If m > 0 Then
rng2 = Replace(Splity, y, Chr(28), , m - 1)
Splity = Replace(Mid(rng2, 1, InStr(rng2, y) - Len(y)), Chr(28), y)
End If
End Function
'加强型 Split 功能的自定义函数2
Function Splitmy(rng, Optional y = " ", Optional n = 0, Optional x = " ")
'y=默认分隔符为空格
'n=从第几节开始取,n为0时全取
'x=默认分隔符为空格,提取分隔符前的字符
rng = rng & y
If n < 0 Then Splitmy = "": Exit Function
If n = 0 Then
Splitmy = rng
Else
rng1 = Replace(rng, y, "", , n - 1)
Splitmy = Mid(rng1, InStr(rng1, y) + Len(y))
End If
If InStr(Splitmy, x) > 0 Then
rng2 = Splitmy
Splitmy = Mid(rng2, 1, InStr(rng2, x) - 1)
End If
End Function
|
评分
-
2
查看全部评分
-
|