Query goal: | A surrogate key is a key that consist of one column. The values of this column do not have any meaning for the user and the system generates the values (integers) automatically. In case of defining a surrogate key in a table it is a common mistake to forget declaring existing natural keys in the table. The query discards tables with only one column. |
Notes about the query: | The query takes into account both external and internal (are created as the result of declaring a column as the identity column) sequence generators. The query takes into account a possibility that a column may be associated with a sequence generator through a domain. The query takes into account that there could be a PostgreSQL-specific exclude constraint (that is a generalization of unique constraint) instead of a unique constraint. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | High (Few or no false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Find and enforce natural keys, i.e., keys that values have a meaning to database end users and are used to refer to the entities outside the software system. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
WITH tables_with_unique AS (SELECT nspname AS schema_name, c.relname AS table_name FROM pg_constraint o INNER JOIN pg_class c on c.oid = o.conrelid INNER JOIN pg_namespace n on n.oid=c.relnamespace WHERE o.contype IN ('x','u') AND nspname NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL)), tables_with_only_surrogate AS (SELECT c.table_schema, c.table_name , c.column_name FROM information_schema.columns c LEFT JOIN information_schema.domains d USING (domain_schema, domain_name) INNER JOIN information_schema.schemata s ON c.table_schema=s.schema_name WHERE (coalesce (c.column_default, d.domain_default) ILIKE '%nextval%' OR c.is_identity='YES') AND c.is_nullable='NO' AND (table_schema, table_name) NOT IN ( SELECT table_schema, table_name FROM tables_with_unique)) SELECT table_schema, table_name FROM tables_with_only_surrogate AS twos WHERE (SELECT Count(*) AS cnt FROM information_schema.columns AS c WHERE c.table_schema=twos.table_schema AND c.table_name=twos.table_name)>1 ORDER BY table_schema, table_name; |
Collection name | Collection description |
---|---|
Find problems about integrity constraints | A selection of queries that return information about the state of integrity constraints in the datadabase. 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 |
---|---|
Default value | Queries of this catergory provide information about the use of default values. |
Sequence generators | Queries of this category provide information about sequence generators and their usage. |
Uniqueness | Queries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes. |
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 |
---|
Smell "Superfluous key": Sharma, T., Fragkoulis, M., Rizou, S., Bruntink, M. and Spinellis, D.: Smelly relations: measuring and understanding database schema quality. In: Proceedings of the 40th International Conference on Software Engineering: Software Engineering in Practice, pp. 55-64. ACM, (2018). |