Goal Find base table columns that name refers to the possibility that these are used to register names. Find base table columns that name refers to the possibility that these are used to register comments/descriptions/etc. Find the cases where a base table contains columns from the both sets and the field size in case of the latter is not at least twice as big as in case of the former. For example, if the name of a service can be 100 character long, then it is quite illogical that the description of the service is only at most 200 characters long.
Notes The query considers both column names in English and Estonian. The query does not take into account the possibility that the maximum field size has been specified by using CHECK constraints. In case of the string_agg function, the line break (br) tag is used as a part of the separator for the better readability in case the query result is displayed in a web browser.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Fixing Suggestion For each textual column one has to find a field size that allows us to register everything that is needed but prohibits registration of total garbage. Increase the field size of the comments/descriptions/etc. column.
Data Source INFORMATION_SCHEMA only
SQL Query
WITH nimetus AS (SELECT table_schema, table_name, column_name, data_type, character_maximum_length
FROM INFORMATION_SCHEMA.columns
WHERE data_type LIKE '%char%' 
AND column_name~*'(nimi|nimetus|pealkiri|name|title)'
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)),
kirjeldus AS (SELECT table_schema, table_name, column_name, data_type, character_maximum_length
FROM INFORMATION_SCHEMA.columns
WHERE data_type LIKE '%char%' 
AND column_name~*'(kirjeldus|kommentaar|selgitus|lugu|description|comment|explanation|story)'
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))
SELECT nimetus.table_schema, nimetus.table_name, 
string_agg(DISTINCT nimetus.column_name  || ' ' || nimetus.data_type || '(' || nimetus.character_maximum_length || ')',';
') AS columns_for_names, string_agg(DISTINCT kirjeldus.column_name || ' ' || kirjeldus.data_type || '(' || kirjeldus.character_maximum_length || ')',';
') AS columns_for_descriptions FROM nimetus, kirjeldus WHERE nimetus.table_schema=kirjeldus.table_schema AND nimetus.table_name=kirjeldus.table_name AND kirjeldus.character_maximum_length
Collections

This query belongs to the following collections:

NameDescription
Find problems about base tablesA 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 automaticallyQueries, 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:

NameDescription
Data typesQueries of this category provide information about the data types and their usage.
Result quality depends on namesQueries of this category use names (for instance, column names) to try to guess the meaning of a database object. Thus, the goodness of names determines the number of false positive and false negative results.
Validity and completenessQueries of this category provide information about whether database design represents the world (domain) correctly (validity) and whether database design captures all the information about the world (domain) that is correct and relevant (completeness).