Query goal: | Find as to whether different precisions/scales are used in case of registering data about sums of money in different columns. |
Notes about the query: | 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. The query considers both column names in English and Estonian. |
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 |
Data source: | INFORMATION_SCHEMA only |
SQL query: | Click on query to copy it
WITH num_cols AS (SELECT table_schema, table_name, column_name, ordinal_position, CASE WHEN numeric_precision IS NOT NULL AND numeric_scale IS NOT NULL THEN data_type || '(' || numeric_precision || ',' || numeric_scale || ')' ELSE data_type END AS data_type FROM INFORMATION_SCHEMA.columns WHERE column_name~*'(hind|maksumus|price|cost)[[:digit:]]*$' AND data_type~*'(numeric|decimal)' 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 data_type, string_agg(table_schema || '.' || table_name || '.' || column_name, ',<br>' ORDER BY table_schema, table_name) AS tables, Count(*) AS number_of_columns FROM num_cols WHERE (SELECT Count(DISTINCT data_type) AS cnt FROM num_cols)>1 GROUP BY data_type ORDER BY Count(*) DESC, data_type; |
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 |
---|---|
Field size | Queries of this category provide information about the maximum size of values that can be recorded in column fields |
Inconsistencies | Queries of this catergory provide information about inconsistencies of solving the same problem in different places. |
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). |