Query goal: | Find base table columns that name refers to the possibility that these are used to register prices/sums of money. Find columns that do not have a numeric type. |
Notes about the query: | 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 |
Fixing suggestion: | Choose data types carefully. Be as precise as possible. In PostgreSQL one should usually use NUMERIC (synonym DECIMAL) type in case of storing price data. One could also use INTEGER type to keep sums of money in cents. Change the data type of the column. Avoid using type MONEY because a) it has embedded currency identifier that depends on the environment and may differ from your requirements and b) one has to cast the value to numeric to make arithmetic calculations. |
Data source: | INFORMATION_SCHEMA only |
SQL query: | Click on query to copy it
SELECT table_schema, table_name, column_name, data_type FROM INFORMATION_SCHEMA.columns WHERE column_name~*'(hind|maksumus|price|cost)[[:digit:]]*$' AND data_type NOT IN ('decimal', 'numeric','integer','smallint','bigint') 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. |
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). |
Reference |
---|
https://stackoverflow.com/questions/15726535/postgresql-which-datatype-should-be-used-for-currency |