Declaring a column to have the type TEXT or the type VARCHAR (without the maximum number of characters) has the same end result in terms of what data can be recorded in the column. Nevertheless, one should try to stick with using one of the type names in order to cause less confusion. "If you do something a certain way, do all similar things in the same way." (Robert C. Martin, Clean Code)
Notes
The query returns data about all the base table columns with the TEXT or VARCHAR type, if there is at least one base table column with the type TEXT and one base table column with the type VARCHAR.
Type
Problem detection (Each row in the result could represent a flaw in the design)
WITH text AS (SELECT table_schema, table_name, column_name, data_type, ordinal_position
FROM INFORMATION_SCHEMA.columns
WHERE data_type='text' AND
(table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') AND
table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
varchar AS (SELECT table_schema, table_name, column_name, data_type, ordinal_position
FROM INFORMATION_SCHEMA.columns
WHERE data_type='character varying' AND character_maximum_length IS NULL AND
(table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') AND
table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
total AS (SELECT table_schema, table_name, column_name, data_type, ordinal_position
FROM text
UNION SELECT table_schema, table_name, column_name, data_type, ordinal_position
FROM varchar)
SELECT table_schema, table_name, column_name, data_type
FROM total
WHERE EXISTS (SELECT 1 FROM text) AND EXISTS (SELECT 1 FROM VARCHAR)
ORDER BY data_type, table_schema, table_name, ordinal_position;
Collections
This query belongs to the following collections:
Name
Description
Find problems about base tables
A selection of queries that return information about the data types, field sizes, default values as well as general structure of base tables. Contains all the types of queries - problem detection, software measure, and general overview
Find problems automatically
Queries, that results point to problems in the database. Each query in the collection produces an initial assessment. However, a human reviewer has the final say as to whether there is a problem or not .
Categories
This query is classified under the following categories:
Name
Description
Comfortability of database evolution
Queries of this category provide information about the means that influence database evolution.
Data types
Queries of this category provide information about the data types and their usage.
Inconsistencies
Queries of this catergory provide information about inconsistencies of solving the same problem in different places.
Further reading and related materials:
Reference
The corresponding code smell in case of cleaning code is "G11: Inconsistency". (Robert C. Martin, Clean Code)