Find base table columns with the Boolean type that has a PRIMARY KEY, UNIQUE, or FOREIGN KEY constraint that involves only this column. Avoid unnecessary constraints. It is quite improbable that there must be such constraints. For instance, a table with PRIMARY KEY () or UNIQUE () constraint can have at most two rows.
Type
Problem detection (Each row in the result could represent a flaw in the design)
with simple_keys as (select
n.nspname as table_schema,
c.relname as table_name,
(SELECT a.attname FROM pg_attribute a WHERE a.attrelid = c.oid AND a.attnum = o.conkey[1] AND a.attisdropped = FALSE) AS column_name,
o.conname AS constraint_name,
CASE WHEN o.contype='p' THEN 'PRIMARY KEY'
WHEN o.contype='u' THEN 'UNIQUE'
ELSE 'FOREIGN KEY' END AS constraint_type
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_namespace n on c.relnamespace=n.oid
where o.contype in ('u', 'p', 'f')
and c.relkind = 'r'
and cardinality(o.conkey)=1
and n.nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
boolean_columns AS (SELECT table_schema, table_name, column_name
FROM INFORMATION_SCHEMA.columns
WHERE data_type='boolean'
AND (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables
WHERE table_type IN ('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 table_schema, table_name, column_name, constraint_name, constraint_type
FROM simple_keys
WHERE (table_schema, table_name, column_name) IN (SELECT table_schema, table_name, column_name
FROM boolean_columns)
ORDER BY table_schema, table_name, column_name;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
with simple_keys as (select
n.nspname as table_schema,
c.relname as table_name,
(SELECT a.attname FROM pg_attribute a WHERE a.attrelid = c.oid AND a.attnum = o.conkey[1] AND a.attisdropped = FALSE) AS column_name,
o.conname AS constraint_name
from pg_constraint o inner join pg_class c on c.oid = o.conrelid
inner join pg_namespace n on c.relnamespace=n.oid
where o.contype in ('u', 'p', 'f')
and c.relkind = 'r'
and cardinality(o.conkey)=1
and n.nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
boolean_columns AS (SELECT table_schema, table_name, column_name
FROM INFORMATION_SCHEMA.columns
WHERE data_type='boolean'
AND (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables
WHERE table_type IN ('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 format('ALTER TABLE %1$I.%2$I DROP CONSTRAINT %3$I CASCADE;', table_schema, table_name, constraint_name) AS statements
FROM simple_keys
WHERE (table_schema, table_name, column_name) IN (SELECT table_schema, table_name, column_name
FROM boolean_columns)
ORDER BY table_schema, table_name, column_name;
Drop the constraints.
Collections
This query belongs to the following collections:
Name
Description
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 .
Categories
This query is classified under the following categories:
Name
Description
Boolean data
Queries of this category provide information about truth-values data that is kept in the database.
Relationships between tables
Queries of this category provide information about how database tables are connected to each other and whether such connections have been explicitly defined and whether it has been done correctly.
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).