MariaDB provides multiple ways of returning the data type of a column. Here are four ways to get the data type of a given column in MariaDB.
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 Products;
Result:
+--------------------+---------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +--------------------+---------------+------+-----+---------+-------+ | ProductId | int(11) | NO | PRI | NULL | | | VendorId | int(11) | NO | MUL | NULL | | | ProductName | varchar(255) | NO | | NULL | | | ProductPrice | decimal(8,2) | NO | | NULL | | | ProductDescription | varchar(1000) | YES | | NULL | | +--------------------+---------------+------+-----+---------+-------+
We can narrow it down to just one column if required:
SHOW COLUMNS FROM Products
WHERE Field = 'ProductName';
Result:
+-------------+--------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-------------+--------------+------+-----+---------+-------+ | ProductName | varchar(255) | NO | | NULL | | +-------------+--------------+------+-----+---------+-------+
The DESCRIBE
/ DESC
Statement
The DESCRIBE
statement is a shortcut for SHOW COLUMNS FROM
syntax:
DESCRIBE Products;
Result:
+--------------------+---------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +--------------------+---------------+------+-----+---------+-------+ | ProductId | int(11) | NO | PRI | NULL | | | VendorId | int(11) | NO | MUL | NULL | | | ProductName | varchar(255) | NO | | NULL | | | ProductPrice | decimal(8,2) | NO | | NULL | | | ProductDescription | varchar(1000) | YES | | NULL | | +--------------------+---------------+------+-----+---------+-------+
Just append the column name to narrow it to one column:
DESCRIBE Products ProductName;
Result:
+-------------+--------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-------------+--------------+------+-----+---------+-------+ | ProductName | varchar(255) | NO | | NULL | | +-------------+--------------+------+-----+---------+-------+
You can also use wildcards:
DESCRIBE Products 'Product%';
Result:
+--------------------+---------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +--------------------+---------------+------+-----+---------+-------+ | ProductId | int(11) | NO | PRI | NULL | | | ProductName | varchar(255) | NO | | NULL | | | ProductPrice | decimal(8,2) | NO | | NULL | | | ProductDescription | varchar(1000) | YES | | NULL | | +--------------------+---------------+------+-----+---------+-------+
You can also shorten it to DESC
:
DESC Products ProductName;
Result:
+-------------+--------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-------------+--------------+------+-----+---------+-------+ | ProductName | varchar(255) | 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 = 'Products'
AND COLUMN_NAME = 'ProductName';
Result:
+-------------+-----------+------------+--------------+ | COLUMN_NAME | DATA_TYPE | MAX_LENGTH | OCTET_LENGTH | +-------------+-----------+------------+--------------+ | ProductName | varchar | 255 | 1020 | +-------------+-----------+------------+--------------+
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 mariadb-show
Utility
The mariadb-show
utility shows the structure of a MariaDB database (databases, tables, columns and indexes).
This utility is run on its own. In other words, don’t run this from within MariaDB. Instead, open a new terminal/command line window and run it from there.
Example:
mariadb-show KrankyKranes Products ProductName
Result:
+-------------+--------------+--------------------+------+-----+---------+-------+---------------------------------+---------+ | Field | Type | Collation | Null | Key | Default | Extra | Privileges | Comment | +-------------+--------------+--------------------+------+-----+---------+-------+---------------------------------+---------+ | ProductName | varchar(255) | utf8mb4_general_ci | NO | | | | select,insert,update,references | | +-------------+--------------+--------------------+------+-----+---------+-------+---------------------------------+---------+
In this example, KrankyKranes
is the name of the database, Products
is the table, and ProductName
is the column that I’m interested in.
This utility can also be accessed using mysqlshow
place of mariadb-show
. The utility accepts quite a few options. See MariaDB’s documentation for more information.