Checkdigit

mail

New Member
Joined
Mar 28, 2013
Messages
3
I need to calculate a check digit for 20,000 large numbers in excel
I can manually do it as follows:
The Number is 33 digits long, each digit is multiplied alternating 1,2,1,2 the right most figure in the products are added together, the right most figure in the sum is subtracted from ten creating the check digit. ten is not a check digit it would be 0. Any help would be appreciated!
1</SPAN>
1</SPAN>
5</SPAN>
0</SPAN>
1</SPAN>
2</SPAN>
0</SPAN>
0</SPAN>
0</SPAN>
5</SPAN>
0</SPAN>
1</SPAN>
0</SPAN>
2</SPAN>
4</SPAN>
6</SPAN>
3</SPAN>
2</SPAN>
0</SPAN>
1</SPAN>
3</SPAN>
1</SPAN>
2</SPAN>
6</SPAN>
0</SPAN>
0</SPAN>
0</SPAN>
0</SPAN>
0</SPAN>
2</SPAN>
5</SPAN>
0</SPAN>
0</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
2</SPAN>
1</SPAN>
1</SPAN>
2</SPAN>
5</SPAN>
0</SPAN>
1</SPAN>
4</SPAN>
0</SPAN>
0</SPAN>
0</SPAN>
10</SPAN>
0</SPAN>
2</SPAN>
0</SPAN>
4</SPAN>
4</SPAN>
12</SPAN>
3</SPAN>
4</SPAN>
0</SPAN>
2</SPAN>
3</SPAN>
2</SPAN>
2</SPAN>
12</SPAN>
0</SPAN>
0</SPAN>
0</SPAN>
0</SPAN>
0</SPAN>
4</SPAN>
5</SPAN>
0</SPAN>
0</SPAN>
1</SPAN>
2</SPAN>
5</SPAN>
1</SPAN>
4</SPAN>
0</SPAN>
2</SPAN>
4</SPAN>
4</SPAN>
2</SPAN>
3</SPAN>
4</SPAN>
2</SPAN>
3</SPAN>
2</SPAN>
2</SPAN>
2</SPAN>
4</SPAN>
5</SPAN>
52</SPAN>
2</SPAN>
10</SPAN>
8</SPAN>
Check Digit</SPAN>

<TBODY>
</TBODY>
 

Excel Facts

Can you AutoAverage in Excel?
There is a drop-down next to the AutoSum symbol. Open the drop-down to choose AVERAGE, COUNT, MAX, or MIN

shg

MrExcel MVP
Joined
May 7, 2008
Messages
21,787
Office Version
  1. 2010
Platform
  1. Windows
Welcome to the board.

Code:
      ----------------A---------------- B
  1   115012000501024632013126000002500 8

The formula in B1 is

=10 - MOD(SUMPRODUCT(MID(A1, ROW(INDIRECT("1:33")), 1) * MID("12", MOD(ROW(INDIRECT("1:33")) - 1, 2) + 1, 1)), 10)
 

mail

New Member
Joined
Mar 28, 2013
Messages
3
That works Thanks, How would I modify it for differnt length numners?
 

shg

MrExcel MVP
Joined
May 7, 2008
Messages
21,787
Office Version
  1. 2010
Platform
  1. Windows
See the two 33's in the formula?
 

shg

MrExcel MVP
Joined
May 7, 2008
Messages
21,787
Office Version
  1. 2010
Platform
  1. Windows

ADVERTISEMENT

Oops:

=MOD(10 - SUMPRODUCT(MID(A1, ROW(INDIRECT("1:33")), 1) * MID("12", MOD(ROW(INDIRECT("1:33")) - 1, 2) + 1, 1)), 10)
 

mail

New Member
Joined
Mar 28, 2013
Messages
3
I changed the 33's to 51's and it seems to work, I had been doing a replace 10 with 0, but the formula is simpler . How does this formula work in words?
Thanks
 

shg

MrExcel MVP
Joined
May 7, 2008
Messages
21,787
Office Version
  1. 2010
Platform
  1. Windows
The first MID function returns an array of individual digits, the second returns the array {1,2,1,2,...}, the SUMPRODUCT mutiplies them and tallies the sum, the result is subtracted from 10, and the MOD function gives the remainder after successive divisions by 10.
 

Watch MrExcel Video

Forum statistics

Threads
1,133,539
Messages
5,659,392
Members
418,500
Latest member
Guru Prasad S

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top