In MySQL, you can run a query like the following to return non-numeric data from the column.
This can be helpful if you ever find a column that contains numeric data, but it was set up as a varchar
or char
column. You can use this query to find any non-numeric values that might have been inserted into the column. You can then deal with it any way you like, such as convert them to numeric, then change the column type.
Sample Data
Suppose we create a table like this:
DROP TABLE IF EXISTS t1;
CREATE TABLE t1 (
c1 varchar(255)
);
INSERT INTO t1 (c1) VALUES
('0'),
('1'),
('+1'),
('-1'),
('.5'),
('00.00'),
('73.45'),
('+73.45'),
('-73.45'),
('.246'),
('-.34e7'),
('12.e-3'),
('1.2e+4'),
('a'),
('9afc'),
('e7'),
('+e0'),
('Ten'),
('5 Dollars');
SELECT * FROM t1;
The table has been created and contains the following rows:
+-----------+ | c1 | +-----------+ | 0 | | 1 | | +1 | | -1 | | .5 | | 00.00 | | 73.45 | | +73.45 | | -73.45 | | .246 | | -.34e7 | | 12.e-3 | | 1.2e+4 | | a | | 9afc | | e7 | | +e0 | | Ten | | 5 Dollars | +-----------+
The column is a varchar(255)
column, so it’s not numeric. It can (and does) contain numbers but these are stored as character data. It can also contain arbitrary text (which it does).
Return All Non-Numeric Values
We can use the following query to return non-numeric values from the above table:
SELECT c1
FROM t1
WHERE c1 NOT REGEXP '^[-+]?[0-9]*\.?[0-9]+([eE][-+]?[0-9]+)?$';
Result:
+-----------+ | c1 | +-----------+ | 12.e-3 | | a | | 9afc | | Ten | | 5 Dollars | +-----------+
Return Non-Integers
If we only want to return non-integers, the query can be a lot simpler:
SELECT c1
FROM t1
WHERE c1 NOT REGEXP '^[0-9]+$';
Result:
+-----------+ | c1 | +-----------+ | +1 | | -1 | | .5 | | 00.00 | | 73.45 | | +73.45 | | -73.45 | | .246 | | -.34e7 | | 12.e-3 | | 1.2e+4 | | a | | 9afc | | e7 | | +e0 | | Ten | | 5 Dollars | +-----------+
Does Not Contain Numeric Data
If we just want to find rows that don’t contain any numeric data, we can do the following:
SELECT c1
FROM t1
WHERE c1 NOT REGEXP '[0-9]+';
Result:
+------+ | c1 | +------+ | a | | Ten | +------+