Home |
Search |
Today's Posts |
|
#1
![]() |
|||
|
|||
![]()
I am trying to create a check digit worksheet for an algorithm where staff
have to use the algorithm hundreds of times daily, so it has to be quick and efficient. The algorithm works where the first 12 digits are multiplied and summed using simple math, and the REMAINDER of the of the sum divided by 9 must equal the 13th digit. For example: My number is 0500450002883, so 1x0=0 2x5=10 3x0=0 4x0=0 5x4=20 6x5=30 7x0=0 8x0=0 9x0=0 10x2=20 11x8=88 12x8=96 where the sum = 264. If you divide 264 by 9, the remaider is 3, the check digit. What formula can I use to produce the remaider for 264/9 instead of getting 29.33? |
#2
![]() |
|||
|
|||
![]()
=MOD(SUMPRODUCT(--(MID(A17,ROW(INDIRECT("1:12")),1)),ROW(INDIRECT("1 :12"))),
9) -- HTH Bob Phillips "Lowkey" wrote in message ... I am trying to create a check digit worksheet for an algorithm where staff have to use the algorithm hundreds of times daily, so it has to be quick and efficient. The algorithm works where the first 12 digits are multiplied and summed using simple math, and the REMAINDER of the of the sum divided by 9 must equal the 13th digit. For example: My number is 0500450002883, so 1x0=0 2x5=10 3x0=0 4x0=0 5x4=20 6x5=30 7x0=0 8x0=0 9x0=0 10x2=20 11x8=88 12x8=96 where the sum = 264. If you divide 264 by 9, the remaider is 3, the check digit. What formula can I use to produce the remaider for 264/9 instead of getting 29.33? |
#3
![]() |
|||
|
|||
![]()
To add to Bob's reply:
The value must be entered as '0500450002883 to preserve the leading zero To check if remainder equals 13th digit: =MOD(SUMPRODUCT(--(MID(A17,ROW(INDIRECT("1:12")),1)),ROW(INDIRECT("1 :12"))), 9)=VALUE(RIGHT(A17)) The INDIRECT is not needed unless you plan to copy the formula to other cells =MOD(SUMPRODUCT(--(MID(A19,ROW(1:12),1)),ROW(1:12)), 9)=VALUE(RIGHT(A19) best wishes Bernard V Liengme www.stfx.ca/people/bliengme remove caps from email "Bob Phillips" wrote in message ... =MOD(SUMPRODUCT(--(MID(A17,ROW(INDIRECT("1:12")),1)),ROW(INDIRECT("1 :12"))), 9) -- HTH Bob Phillips "Lowkey" wrote in message ... I am trying to create a check digit worksheet for an algorithm where staff have to use the algorithm hundreds of times daily, so it has to be quick and efficient. The algorithm works where the first 12 digits are multiplied and summed using simple math, and the REMAINDER of the of the sum divided by 9 must equal the 13th digit. For example: My number is 0500450002883, so 1x0=0 2x5=10 3x0=0 4x0=0 5x4=20 6x5=30 7x0=0 8x0=0 9x0=0 10x2=20 11x8=88 12x8=96 where the sum = 264. If you divide 264 by 9, the remaider is 3, the check digit. What formula can I use to produce the remaider for 264/9 instead of getting 29.33? |
#4
![]() |
|||
|
|||
![]() "Bernard Liengme" wrote in message ... The value must be entered as '0500450002883 to preserve the leading zero You could always force it =MOD(SUMPRODUCT(--(MID(TEXT(A1,"0000000000000"),ROW(INDIRECT("1:12") ),1)),RO W(INDIRECT("1:12"))),9) |
#5
![]() |
|||
|
|||
![]()
Bob Phillips wrote...
.... You could always force it =MOD(SUMPRODUCT(--(MID(TEXT(A1,"0000000000000"),ROW(INDIRECT("1:12") ),1)), ROW(INDIRECT("1:12"))),9) Why not just treat it as a number in the first place? =MOD(SUMPRODUCT(INT(A1/10^{1;2;3;4;5;6;7;8;9;10;11;12}) -10*INT(A1/10^{2;3;4;5;6;7;8;9;10;11;12;13}), {12;11;10;9;8;7;6;5;4;3;2;1}),9) This is lots longer, but if you name the array something like ARRAY, it becomes =MOD(SUMPRODUCT(INT(A1/10^ARRAY)-10*INT(A1/10^(1+ARRAY)),13-ARRAY),9) |
Reply |
Thread Tools | Search this Thread |
Display Modes | |
|
|
![]() |
||||
Thread | Forum | |||
Complicated Challenge | Excel Discussion (Misc queries) | |||
A Challenge | Excel Worksheet Functions | |||
MATCH FUNCTION?...challenge | Excel Worksheet Functions | |||
Comparison Challenge | Excel Discussion (Misc queries) | |||
Divide Ranks into two teams (mathematical guru challenge) | Excel Discussion (Misc queries) |