Find base table columns with CHAR(n) or VARCHAR(n) type and make sure that n is not too big or too small. Also make sure that you do not use CHAR(n) in case of columns that have to keep variable length strings. "Values of type character are physically padded with spaces to the specified width n, and are stored and displayed that way" (https://www.postgresql.org/docs/current/datatype-character.html)
Notes
Query returns also information about columns that properties have been specified through a domain.
Type
General (Overview of some aspect of the database.)
Change the field size. If the column is specified through a domain, then you have to create a new domain and associate the column with the new domain because you cannot change the field size with the ALTER DOMAIN statement.
Data Source
INFORMATION_SCHEMA only
SQL Query
SELECT table_schema, table_name, column_name, data_type, character_maximum_length
FROM INFORMATION_SCHEMA.columns
WHERE data_type LIKE '%char%' AND character_maximum_length IS NOT 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)
ORDER BY data_type, character_maximum_length DESC, table_schema, table_name, ordinal_position;
Collections
This query belongs to the following collections:
Name
Description
Find problems by overview
Queries that results point to different aspects of database that might have problems. A human reviewer has to decide based on the results as to whether there are problems or not .
Categories
This query is classified under the following categories:
Name
Description
Data types
Queries of this category provide information about the data types and their usage.