The list of all the queries

Simple natural primary keys

Query goal: Find primary keys that consist of one column and that values are not generated by the system.
Notes about the query: Find primary keys that consist of one column, where the column is not a part of a foreign key and does not have an associated sequence generator.
Query type: General (Overview of some aspect of the database.)
Query license: MIT License
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

with keys as (select 
(select nspname from pg_namespace where oid=c.relnamespace) as key_schema,
c.relname as key_table, 
c.oid as key_table_oid,
o.conkey AS key_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype in ('p') and cardinality(o.conkey)=1),
keys_unnest as (select key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
from keys, unnest(keys.key_col) with ordinality as k(key_col_num, ordin)),
keys_with_names AS (select key_schema, key_table, a_key.attname as key_col
from keys_unnest k inner join pg_attribute a_key on k.key_col_num = a_key.attnum and k.key_table_oid = a_key.attrelid and a_key.attisdropped = false
),
fk as (select 
(select nspname from pg_namespace where oid=c.relnamespace) as key_schema,
c.relname as key_table, 
c.oid as key_table_oid,
o.conkey AS key_col
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
where o.contype='f'),
fk_unnest as (select key_schema, key_table, key_table_oid, key_col, key_col_num, ordin
from fk, unnest(fk.key_col) with ordinality as k(key_col_num, ordin)),
fk_with_names AS (select key_schema, key_table, a_key.attname as key_col
from fk_unnest k inner join pg_attribute a_key on k.key_col_num = a_key.attnum and k.key_table_oid = a_key.attrelid and a_key.attisdropped = false),
key_not_fk AS (select key_schema, key_table, key_col
from keys_with_names
except select key_schema, key_table, key_col
from fk_with_names)
SELECT c.table_schema, c.table_name , c.column_name, 
CASE WHEN c.data_type ILIKE 'character%' AND c.character_maximum_length IS NOT NULL THEN c.data_type || '(' || c.character_maximum_length::text || ')'
WHEN c.data_type ILIKE 'timestamp%' AND c.datetime_precision IS NOT NULL THEN c.data_type || '(' || c.datetime_precision || ')'
WHEN c.data_type ILIKE 'numeric%' AND c.numeric_precision IS NOT NULL THEN c.data_type || '(' || c.numeric_precision::text || ',' ||coalesce(c.numeric_scale,0)::text || ')'
WHEN c.data_type ILIKE 'interval%' AND c.interval_type IS NOT NULL THEN c.data_type || '(' || c.interval_type::text || ')'
WHEN c.data_type='USER-DEFINED' THEN c.udt_schema || '.' || c.udt_name 
ELSE c.data_type END AS data_type
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) NOT ILIKE '%nextval%' OR coalesce (c.column_default, d.domain_default) IS NULL) AND c.is_identity='NO')
AND (c.table_schema = 'public'
OR s.schema_owner<>'postgres')
AND EXISTS (SELECT *
FROM key_not_fk AS k
WHERE k.key_schema=c.table_schema
AND k.key_table=c.table_name
AND k.key_col=c.column_name)
ORDER BY table_schema, table_name;

Collections where the query belongs to

Collection nameCollection description
Find problems about integrity constraintsA 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 by overviewQueries that results point to different aspects of database that might have problems. A human reviewer has to decide based on the results as to whether there are problems or not .

Categories where the query belongs to

Category nameCategory description
UniquenessQueries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes.

The list of all the queries