Here are four ways to get the data type of a column in MySQL.
The SHOW COLUMNS
Statement
The SHOW COLUMNS
statement displays information about the columns in a given table or view. We can pass the name of the table or view to return information on its columns:
SHOW COLUMNS FROM Pets;
Result:
+-----------+-------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-----------+-------------+------+-----+---------+-------+ | PetId | int | NO | PRI | NULL | | | PetTypeId | int | NO | | NULL | | | OwnerId | int | NO | | NULL | | | PetName | varchar(60) | NO | | NULL | | | DOB | date | YES | | NULL | | +-----------+-------------+------+-----+---------+-------+
We can narrow it down to just one column if required:
SHOW COLUMNS FROM Pets
WHERE Field = 'PetName';
Result:
+---------+-------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +---------+-------------+------+-----+---------+-------+ | PetName | varchar(60) | NO | | NULL | | +---------+-------------+------+-----+---------+-------+
The DESCRIBE
/ DESC
Statement
The DESCRIBE
statement is a shortcut for the SHOW COLUMNS FROM
syntax:
DESCRIBE Pets;
Result:
+-----------+-------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-----------+-------------+------+-----+---------+-------+ | PetId | int | NO | PRI | NULL | | | PetTypeId | int | NO | | NULL | | | OwnerId | int | NO | | NULL | | | PetName | varchar(60) | NO | | NULL | | | DOB | date | YES | | NULL | | +-----------+-------------+------+-----+---------+-------+
Just append the column name to narrow it to one column:
DESCRIBE Pets PetName;
Result:
+---------+-------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +---------+-------------+------+-----+---------+-------+ | PetName | varchar(60) | NO | | NULL | | +---------+-------------+------+-----+---------+-------+
You can also use wildcards:
DESCRIBE Pets 'Pet%';
Result:
+-----------+-------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-----------+-------------+------+-----+---------+-------+ | PetId | int | NO | PRI | NULL | | | PetTypeId | int | NO | | NULL | | | PetName | varchar(60) | NO | | NULL | | +-----------+-------------+------+-----+---------+-------+
You can also shorten it to DESC
:
DESC Pets PetName;
Result:
+---------+-------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +---------+-------------+------+-----+---------+-------+ | PetName | varchar(60) | NO | | NULL | | +---------+-------------+------+-----+---------+-------+
The information_schema.columns
View
The information_schema.columns
view contains information about columns:
SELECT
COLUMN_NAME,
DATA_TYPE,
CHARACTER_MAXIMUM_LENGTH AS MAX_LENGTH,
CHARACTER_OCTET_LENGTH AS OCTET_LENGTH
FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_SCHEMA = DATABASE()
AND TABLE_NAME = 'Pets'
AND COLUMN_NAME = 'PetName';
Result:
+-------------+-----------+------------+--------------+ | COLUMN_NAME | DATA_TYPE | MAX_LENGTH | OCTET_LENGTH | +-------------+-----------+------------+--------------+ | PetName | varchar | 60 | 240 | +-------------+-----------+------------+--------------+
In this case I used the DATABASE()
function to return the name of the current database. You could alternatively use the name of a specific database.
The mysqlshow
Utility
The mysqlshow
utility shows the structure of a MySQL database (databases, tables, columns and indexes).
This utility is run on its own. In other words, don’t run this from within MySQL. Instead, open a new terminal/command line window and run it from there.
Example:
mysqlshow -u root PetHotel Pets PetName
Result:
+---------+-------------+--------------------+------+-----+---------+-------+---------------------------------+---------+ | Field | Type | Collation | Null | Key | Default | Extra | Privileges | Comment | +---------+-------------+--------------------+------+-----+---------+-------+---------------------------------+---------+ | PetName | varchar(60) | utf8mb4_0900_ai_ci | NO | | | | select,insert,update,references | | +---------+-------------+--------------------+------+-----+---------+-------+---------------------------------+---------+
In this example, PetHotel
is the name of the database, Pets
is the table, and PetName
is the column that I’m interested in.
I also provided the username for which to connect with. The utility accepts quite a few options. See the MySQL documentation for more information.