Find schema objects that name starts with the schema name and then has at least one more symbol. "Shorter names are generally better than longer ones, so long as they are clear. Add no more context to a name than is necessary" (Robert C. Martin, Clean Code) Shema is a namespace. There cannot be in the same schema two schema objects that belong to the same name class and have the same name.
Notes
In some case the query may return false positive results. For instance, schema public may contain table public opinion.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Rename the schema object. Remove reference to the schema from the name. Use a consistent style of naming.
Data Source
system catalog only
SQL Query
WITH named_objects AS (
SELECT
c.oid,
n.nspname AS schema_name,
c.relname AS object_name,
CASE WHEN c.relkind='r' THEN 'BASE TABLE'
WHEN c.relkind='S' THEN 'SEQUENCE GENERATOR'
WHEN c.relkind='v' THEN 'VIEW'
WHEN c.relkind='m' THEN 'MATERIALIZED VIEW'
WHEN c.relkind='c' THEN 'COMPOSITE TYPE'
WHEN c.relkind='f' THEN 'FOREIGN TABLE'
WHEN c.relkind='p' THEN 'PARTITIONED TABLE'
WHEN c.relkind='I' THEN 'PARTITIONED INDEX'
END AS object_type
FROM pg_namespace AS n INNER JOIN pg_authid AS a ON n.nspowner=a.oid
INNER JOIN pg_class AS c ON n.oid=c.relnamespace
WHERE (n.nspname='public' OR a.rolname<>'postgres')
AND relkind NOT IN ('t','i')
UNION SELECT
c.oid,
n.nspname AS schema_name,
c.relname AS object_name,
'INDEX' AS object_type
FROM pg_namespace AS n INNER JOIN pg_authid AS a ON n.nspowner=a.oid
INNER JOIN pg_class AS c ON n.oid=c.relnamespace
INNER JOIN pg_index AS i ON i.indexrelid=c.oid
WHERE (n.nspname='public' OR a.rolname<>'postgres')
AND i.indisprimary = FALSE
AND i.indisexclusion =FALSE
UNION ALL SELECT
pt.oid,
n.nspname AS schema_name,
pt.typname AS object_name,
CASE WHEN pt.typtype='d' THEN 'DOMAIN'
WHEN pt.typtype='e' THEN 'ENUMERATION TYPE'
WHEN pt.typtype='r' THEN 'RANGE TYPE' END AS object_type
FROM pg_namespace AS n INNER JOIN pg_authid AS a ON n.nspowner=a.oid
INNER JOIN pg_type AS pt ON n.oid=pt.typnamespace
WHERE (n.nspname='public' OR a.rolname<>'postgres')
AND pt.typtype NOT IN ('b','c')
UNION ALL SELECT
pc.oid,
n.nspname AS schema_name,
pc.proname AS object_name,
CASE WHEN pc.prokind='f' THEN 'FUNCTION'
WHEN pc.prokind='p' THEN 'PROCEDURE'
WHEN pc.prokind='a' THEN 'AGGREGATE FUNCTION'
WHEN pc.prokind='w' THEN 'WINDOW FUNCTION' END AS object_type
FROM pg_namespace AS n INNER JOIN pg_authid AS a ON n.nspowner=a.oid
INNER JOIN pg_proc AS pc ON n.oid=pc.pronamespace
WHERE (nspname='public' OR rolname<>'postgres')
),
named_user_defined_objects AS (
SELECT schema_name, object_name, object_type
FROM named_objects nob
WHERE NOT EXISTS (SELECT 1
FROM pg_catalog.pg_depend d
WHERE EXISTS (SELECT 1 FROM pg_catalog.pg_extension e WHERE d.refobjid=e.oid) AND
d.objid=nob.oid)
)
SELECT schema_name, object_name AS suspected_name, object_type
FROM named_user_defined_objects
WHERE object_name ILIKE schema_name || '_%'
ORDER BY object_type, schema_name, object_name;
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
Comfortability of data management
Queries of this category provide information about the means that have been used to make the use or management of database more comfortable and thus, more efficient.
Naming
Queries of this category provide information about the style of naming.
Further reading and related materials:
Reference
The corresponding code problem in case of cleaning code is "Don’t Add Gratuitous Context". (Robert C. Martin, Clean Code)