Here is a UDF (User Defined Function) that will work. You must open the VBA editor, (right click on a sheet tab and select "View Code.")
In the Editor make sure that the "Project Explorer" window is in View, (View Menu.)
Right Click on the VBAProject(Your Workbook Name) and select Insert >> Module.
Double click on that new module in the Project Explorer and paste this code in the right hand pane of the Editor.
Option Explicit
FunctionCountDigits(RangeToAnalyze As Range, _
DigitPosition As Integer, _
DigitToCount As Integer As Long
Dim Cel As Range
Dim X As Long
For Each Cel In RangeToAnalyze
If Mid(CStr(Cel), DigitPosition, 1) = CStr(DigitToCount) Then
X = X + 1
End If
Next Cel
CountDigits = X
End Function
To use this Function in your worksheet, in a Cell, type the = sign, then click the fx button on the formula bar to Insert a Function. At the bottom of the "or Select a Category" dropdown list, select "User Defined Function" and select CountDigits. Then follow the Wizard instructions.
You can also type in the Cell
Then Select the Range you want to use, then type a comma, the digit position to count, then a comma, the the digit to count, and a closing parenthesis.
=CountDigits($A$1:$A$10,3,1)
That example will count all the 1's in the third position. By using the Dolloar signs in the Range assignment, you can copy and paste the formula, and only have to change the position and digit in the new location.
The Function is CountDigits(RaPiDly) or R for Range, P for Position, D for Digit. It should work for numbers up to 32,000 digits long