Query goal: | Find base table columns that name refers to the possibility that these are used to register comments/descriptions. Find the columns where the data type is not VARCHAR and TEXT or in case of VARCHAR the maximum number of permitted characters is smaller than 1000. In case of determining field sizes choose a size that permits registration of all possible legal values. |
Notes about the query: | The query considers both column names in English and Estonian. The query tries to avoid finding boolean columns that regulate displaying comments. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | Medium (Medium number of false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Choose data types carefully. Be as precise as possible. In PostgreSQL one should use VARCHAR or TEXT types in order to store comments and descriptions. The max character length should be at least 1000. Change the data type or the field size of the column. |
Data source: | INFORMATION_SCHEMA only |
SQL query: | Click on query to copy it
SELECT table_schema, table_name, column_name, data_type, character_maximum_length FROM INFORMATION_SCHEMA.columns WHERE column_name~*'(komment|kirjeldus|comment|descr|selgitus)' AND column_name!~*'(id|nr|kood|code|aeg|time|kp|date)$' AND NOT (data_type='boolean' AND column_name~*'(show|display|enable|disable|naita|peida)') AND (data_type NOT IN ('character varying', 'text') OR (data_type='character varying' AND character_maximum_length<1000)) 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 table_schema, table_name, ordinal_position; |
Collection name | Collection 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 . |
Category name | Category description |
---|---|
Data types | Queries of this category provide information about the data types and their usage. |
Field size | Queries of this category provide information about the maximum size of values that can be recorded in column fields |
Result quality depends on names | Queries 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 completeness | Queries 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). |