Query goal: | Find base tables without any unique constraints and primary key as well as any unique index, whether it is created explicitly by a developer or automatically by the DBMS. The only legitimate reason of such a table is if it is an abstract table that is used to define common columns of subtables. |
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: | Declare the PRIMARY KEY constraint and possibly UNIQUE (or EXCLUDE) constraints. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
WITH unique_indexes AS (SELECT n.nspname AS sch, c2.relname AS tbl FROM pg_catalog.pg_class AS c INNER JOIN pg_catalog.pg_index AS i ON i.indexrelid = c.oid INNER JOIN pg_catalog.pg_class AS c2 ON i.indrelid = c2.oid INNER JOIN pg_catalog.pg_namespace AS n ON c.relnamespace = n.oid INNER JOIN pg_catalog.pg_authid AS u ON n.nspowner = u.oid WHERE c.relkind = 'i' AND i.indisunique=TRUE AND (n.nspname = 'public' OR u.rolname <> 'postgres')) SELECT A.table_schema, A.table_name FROM INFORMATION_SCHEMA.tables A INNER JOIN INFORMATION_SCHEMA.schemata B ON A.table_schema=B.schema_name WHERE A.table_type='BASE TABLE' AND (A.table_schema = 'public' OR B.schema_owner<>'postgres') AND (A.table_schema, A.table_name) NOT IN (SELECT sch, tbl FROM unique_indexes) ORDER BY A.table_schema, A.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 |
---|---|
Performance | Queries of this category provide information about indexes in a database. |
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). |