Find derived table columns that name refers to the possibility that these contain person names. The names of derived table columns that contain person names should refer to the role that the corresponding entity type has in the view. For instance, if view active_product has a column with the name surname, then the column name does not give information what is the role of the person in the context of the view. Better name would be, for instance, registrator_surname.
Notes
The query considers both views and materialized views. The query considers both column names in English and Estonian.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Add meaningful context to the name. Rename the column. Give to it more descriptive name. Follow a naming convention. To do this one has to drop the derived table and recreate it.
Data Source
INFORMATION_SCHEMA+system catalog
SQL Query
WITH columns AS (SELECT table_schema, table_name, 'VIEW' AS table_type, column_name
FROM information_schema.columns
WHERE (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='VIEW')
UNION SELECT nspname, relname, 'MATERIALIZED VIEW' AS table_type, attname
FROM pg_class INNER JOIN pg_namespace ON pg_class.relnamespace=pg_namespace.oid
INNER JOIN pg_attribute ON pg_class.oid=pg_attribute.attrelid
WHERE relkind = 'm' AND attnum>=1 AND attisdropped='f')
SELECT table_schema, table_name, table_type, column_name AS suspected_column_name
FROM columns
WHERE column_name~*'^([[:alpha:]]|_){0,3}(eesnimi|perenimi|isanimi|isiku([_]|[ ])*nimi|inimese([_]|[ ])*nimi|inimene|isik|first([_]|[ ])*name|last([_]|[ ])*name|surname|given([_]|[ ])*name|family([_]|[ ])*name|personal([_]|[ ])*name|person)([[:alpha:]]|_){0,3}$' 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)
ORDER BY table_schema, table_name, column_name;
SQL statements that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
SELECT DISTINCT format('DROP VIEW %1$I.%2$I;', table_schema, table_name) AS statements
FROM information_schema.columns
WHERE (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='VIEW')
AND column_name~*'^([[:alpha:]]|_){0,3}(eesnimi|perenimi|isanimi|isiku([_]|[ ])*nimi|inimese([_]|[ ])*nimi|inimene|isik|first([_]|[ ])*name|last([_]|[ ])*name|surname|given([_]|[ ])*name|family([_]|[ ])*name|personal([_]|[ ])*name|person)([[:alpha:]]|_){0,3}$'
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)
ORDER BY statements;
Drop the view.
SELECT DISTINCT format('DROP MATERIALIZED VIEW %1$I.%2$I;', nspname, relname) AS statements
FROM pg_class INNER JOIN pg_namespace ON pg_class.relnamespace=pg_namespace.oid
INNER JOIN pg_attribute ON pg_class.oid=pg_attribute.attrelid
WHERE relkind = 'm' AND attnum>=1 AND attisdropped='f'
AND attname~*'^([[:alpha:]]|_){0,3}(eesnimi|perenimi|isanimi|isiku([_]|[ ])*nimi|inimese([_]|[ ])*nimi|inimene|isik|first([_]|[ ])*name|last([_]|[ ])*name|surname|given([_]|[ ])*name|family([_]|[ ])*name|personal([_]|[ ])*name|person)([[:alpha:]]|_){0,3}$'
AND nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)
ORDER BY statements;
Drop the materialized view.
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.
Derived tables
Queries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.
Naming
Queries of this category provide information about the style of naming.
Further reading and related materials:
Reference
The corresponding code smells in case of cleaning code are "N1: Choose Descriptive Names" and "N4: Unambiguous Names". (Robert C. Martin, Clean Code)
The corresponding code problem in case of cleaning code is "Add Meaningful Context". (Robert C. Martin, Clean Code)