Data Validation - Numbers only (can be multiple)

surkdidat

Well-known Member
Joined
Oct 1, 2011
Messages
594
Office Version
  1. 365
How do I have Data Validation that can only contain numbers (no text, punctuation etc). I have tried ISNUMBER, however, the field can contain two separate numbers i.e. 33 34 can be a valid entry, but 33, 34 or 34 & 35 should not be accepted
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
How about

=ISNUMBER(VALUE(SUBSTITUTE(A1," ","")))
 
Upvote 0
Hey there,

Try this Data Validation in cell A1 for example:
Allow: Custom
Formula: =ISNUMBER(SUBSTITUTE(A1," ","")+0)
 
Upvote 0
If only ONE space is permitted between each number, try this data validation custom formula

=AND(ISNUMBER(VALUE(SUBSTITUTE(A1," ",""))),LEN(A1)=LEN(SUBSTITUTE(A1," ","")))
 
Upvote 0
Just did some further tests on this and it won't currently like if your number resembles that of a number using comma format, for example try in the cell: 345, 678
It will allow that because it sees it as a number (it uses comma separation which is normal)
To get around this try this adapted formula:
=IF(ISNUMBER(SEARCH(",",A1)),FALSE,ISNUMBER(SUBSTITUTE(A1," ","")+0))

Now if you try 345, 678 in the cell it won't allow it!
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,249
Members
452,623
Latest member
Techenthusiast

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
Back
Top