The list of all the queries

Cannot register all legal e-mail addresses

Query goal: Find CHECK constraints on base table or foreign table columns that contain data about e-mail addresses and apply unnecessary restrictions to the these, rejecting potentially some legal addresses. More precisely, find CHECK constraints that prevent registration of e-mail addresses with multiple @ signs.
Notes about the query: The query takes into account only constraints that are associated with exactly one column. Thus, there could be constraints that apply restrictions to multiple columns that still reject legal values. The query takes into account constraints that are associated directly with the column as well as constraints that are associated with the column through a domain. The query does not find CHECK constraints of domains that are not associated with any table. 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: Drop the constraints.
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH ck AS (SELECT 
o.conname,
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS target_schema,
c.relname AS target_table, 
c.oid As target_table_oid,
unnest(o.conkey) AS target_col,
substring(pg_get_constraintdef(o.oid),7) AS consrc,
CASE WHEN c.relkind='r' THEN 'BASE TABLE'
WHEN c.relkind='f' THEN 'FOREIGN'
ELSE 'TABLE' END AS table_type
FROM pg_constraint o INNER JOIN pg_class c ON c.oid = o.conrelid
WHERE o.contype = 'c' AND cardinality(o.conkey)=1),
checks AS (
SELECT ck.target_schema AS table_schema, ck.target_table AS table_name,  table_type, a_target.attname AS column_name, ck.consrc AS check_clause, ck.conname AS constraint_name, 'TABLE CHECK' AS check_type 
FROM ck INNER JOIN pg_attribute a_target ON ck.target_col = a_target.attnum AND ck.target_table_oid = a_target.attrelid AND a_target.attisdropped = FALSE
WHERE ck.target_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
UNION SELECT cdu.table_schema, cdu.table_name, t.table_type, cdu.column_name, cc.check_clause, cc.constraint_name, 'DOMAIN CHECK' AS check_type
FROM INFORMATION_SCHEMA.column_domain_usage AS cdu INNER JOIN INFORMATION_SCHEMA.tables AS t USING (table_schema, table_name)
INNER JOIN INFORMATION_SCHEMA.domain_constraints AS dc USING (domain_schema, domain_name)
INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc USING (constraint_schema, constraint_name)
WHERE t.table_type IN ('BASE TABLE','FOREIGN') AND cc.check_clause NOT LIKE '%IS NOT NULL'  AND 
cdu.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, table_type, column_name, check_clause, constraint_name, check_type
FROM checks
WHERE column_name~*'e[_-]*(mail|meil)'
AND check_clause~*'@.*@'
ORDER BY table_schema, table_name, column_name;

SQL statements for generating SQL statements that help us to fix the problem

SQL queryDescription
WITH ck AS (SELECT 
o.conname,
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS target_schema,
c.relname AS target_table, 
c.oid As target_table_oid,
unnest(o.conkey) AS target_col,
substring(pg_get_constraintdef(o.oid),7) AS consrc,
CASE WHEN c.relkind='r' THEN 'BASE TABLE'
WHEN c.relkind='f' THEN 'FOREIGN'
ELSE 'TABLE' END AS table_type
FROM pg_constraint o INNER JOIN pg_class c ON c.oid = o.conrelid
WHERE o.contype = 'c' AND cardinality(o.conkey)=1),
checks AS (
SELECT ck.target_schema AS table_schema, ck.target_table AS table_name,  table_type, a_target.attname AS column_name, ck.consrc AS check_clause, ck.conname AS constraint_name
FROM ck INNER JOIN pg_attribute a_target ON ck.target_col = a_target.attnum AND ck.target_table_oid = a_target.attrelid AND a_target.attisdropped = FALSE
WHERE ck.target_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 %4$s TABLE %1$I.%2$I DROP CONSTRAINT %3$I;', table_schema, table_name, constraint_name, CASE WHEN table_type='FOREIGN' THEN table_type END) AS statements
FROM checks
WHERE column_name~*'e[_-]*(mail|meil)'
AND check_clause~*'@.*@'
ORDER BY table_schema, table_name, column_name;
Drop the constraint that is directly associated with the table.
WITH ck AS (SELECT 
o.conname,
(SELECT nspname FROM pg_namespace WHERE oid=c.relnamespace) AS target_schema,
c.relname AS target_table, 
c.oid As target_table_oid,
unnest(o.conkey) AS target_col,
substring(pg_get_constraintdef(o.oid),7) AS consrc
FROM pg_constraint o INNER JOIN pg_class c ON c.oid = o.conrelid
WHERE o.contype = 'c' AND cardinality(o.conkey)=1),
checks AS (
SELECT cdu.domain_schema, cdu.domain_name, cdu.table_name, cdu.column_name, cc.check_clause, cc.constraint_name
FROM INFORMATION_SCHEMA.column_domain_usage AS cdu INNER JOIN INFORMATION_SCHEMA.tables AS t USING (table_schema, table_name)
INNER JOIN INFORMATION_SCHEMA.domain_constraints AS dc USING (domain_schema, domain_name)
INNER JOIN INFORMATION_SCHEMA.check_constraints AS cc USING (constraint_schema, constraint_name)
WHERE t.table_type IN ('BASE TABLE','FOREIGN') AND cc.check_clause NOT LIKE '%IS NOT NULL'  AND 
cdu.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 DISTINCT format('ALTER DOMAIN %1$I.%2$I DROP CONSTRAINT %3$I;', domain_schema, domain_name, constraint_name) AS statements
FROM checks
WHERE column_name~*'e[_-]*(mail|meil)'
AND check_clause~*'@.*@'
ORDER BY statements;
Drop the domain constraint.

Collections where the query belongs to

Collection nameCollection description
Find problems automaticallyQueries, 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 where the query belongs to

Category nameCategory description
CHECK constraintsQueries of this category provide information about CHECK constraints.
Result quality depends on namesQueries 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 completenessQueries 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 materials for further reading

Reference
https://help.returnpath.com/hc/en-us/articles/220560587-What-are-the-rules-for-email-address-syntax-

The list of all the queries