=MOD(1000-SUM(IF(MOD(ROW(INDIRECT("1:"&LEN(A1&0))),2)=1,--MID(A1&0,1+LEN(A1&0)-ROW(INDIRECT("1:"&LEN(A1&0))),1),MOD(2*MID(A1&0,1+LEN(A1&0)-ROW(INDIRECT("1:"&LEN(A1&0))),1),10)+INT(2*MID(A1&0,1+LEN(A1&0)-ROW(INDIRECT("1:"&LEN(A1&0))),1)/10))),10)
Function Mod10ChkDig(ByVal sKeyline As String) As String
Dim iSum As Integer, iCharVal As Integer, i As Integer
' Remove spaces
sKeyline = Replace(sKeyline, " ", "")
' Must have between 3 and 15 characters
If Len(sKeyline)< 3 Or Len(sKeyline) > 15 Then
Mod10ChkDig = "Invalid number of characters in Keyline"
Exit Function
End If
' Characters allowed: digits, letters and slash
If sKeyline Like "*[!0-9a-zA-Z/]*" Then
Mod10ChkDig = "Invalid characters in Keyline"
Exit Function
End If
' Calculates check digit
For i = 1 To Len(sKeyline)
iCharVal = (1 + i Mod 2) * (Asc(Mid(sKeyline, i, 1)) And 15)
iCharVal = (iCharVal \ 10) + (iCharVal Mod 10)
iSum = iSum + iCharVal + IIf(iCharVal = 10, -9, 0)
Next
Mod10ChkDig = (10 - (iSum Mod 10)) Mod 10
End Function
Mod10.xls | |||||||
---|---|---|---|---|---|---|---|
A | B | C | D | E | |||
1 | Keylinew/o CheckDigit | CheckDigit Specs | CheckDigit Calculated | Keylinewith CheckDigit | Test | ||
2 | JLSTMS6796 | 9 | 9 | JLSTMS67969 | OK | ||
3 | TMS1112/62 | 3 | 3 | TMS1112/623 | OK | ||
4 | 218XN91LMS | 4 | 4 | 218XN91LMS4 | OK | ||
5 | ABC999NN//3 | 2 | 2 | ABC999NN//32 | OK | ||
6 | OTUBIKALAM | 8 | 8 | OTUBIKALAM8 | OK | ||
7 | ANIT028 | 1 | 1 | ANIT0281 | OK | ||
8 | SEIRAMT | 4 | 4 | SEIRAMT4 | OK | ||
9 | 0012//// | 8 | 8 | 0012////8 | OK | ||
10 | 1402498149 | 0 | 0 | 14024981490 | OK | ||
11 | 811NIS000111 | 9 | 9 | 811NIS0001119 | OK | ||
12 | AEIOUW | 0 | 0 | AEIOUW0 | OK | ||
13 | 1234567890 | 7 | 7 | 12345678907 | OK | ||
14 | DSC1402 | 0 | 0 | DSC14020 | OK | ||
15 | 0987654321 | 3 | 3 | 09876543213 | OK | ||
Sheet2 |
I'm glad I was able to help.
Cheers
PGC