The list of all the queries

Check as to wheteher the names of columns are in the plural or in the singular form (English version) (aggregate view)

Query goal: Check as to wheteher the names of table columns are in the plural or in the singular form. Make sure that you are consistent in naming. Show the number of columns that name is in plural or in singular by table type.
Notes about the query: The query works somewhat correctly only if the names are in English. The query is based on a simplified assumption that in case of many words in English (of course, not all) the plural form is indicated by the letter "s" at the end of the word. If the name or its subcomponent ends with s and it is not preceded with an underscore and a single letter or a letter "s", then it is considered plural. The query tries to give suggestions whether the column name should be in singular or plural form. For that it also considers the type of the column. For instance, array, xml, and json values can contain data about multiple entities or relationships and thus the name of the column that has the type should better be in plural. The names of colums with a numeric type are considered OK even if they are in plural because it is assumed that the value shows the number of entities. Thus, nr_of_docs with type INT is considered to be plural and OK whereas docs with type TEXT is considered to be plural and not OK.
Query type: Sofware measure (Numeric values (software measures) about the database)
Query license: MIT License
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH columns AS (SELECT nspname AS table_schema, relname AS table_name, 
CASE WHEN relkind='r' THEN 'BASE TABLE'
WHEN relkind='v' THEN 'VIEW'
WHEN relkind='m' THEN 'MATERIALIZED VIEW'
WHEN relkind='f' THEN 'FOREIGN TABLE'
WHEN relkind='p' THEN 'PARTITIONED TABLE'
END AS table_type, 
attname AS column_name,
CASE WHEN typbasetype=0 THEN pg_type.typname 
ELSE (SELECT typname 
FROM pg_type AS domain_type
WHERE domain_type.oid=pg_type.typbasetype) END AS column_type,
CASE WHEN attndims<>0 OR typndims<>0 THEN TRUE ELSE FALSE END AS is_array
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
INNER JOIN pg_type ON pg_attribute.atttypid =pg_type.oid
WHERE attnum>=1 
AND relkind IN ('r','v','m','f','p')
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)),
plural_or_singular AS (SELECT table_schema, table_name, table_type, column_name, 
CASE WHEN is_array=FALSE THEN column_type ELSE 'ARRAY [' || translate(column_type,'_','') || ']' END AS column_type, 
CASE WHEN (regexp_replace(column_name,'(stats_|stats$|status|state|is_|has_|pos$|alias|cvs|address|value$|key$|pays$|group$|lock$|_to$|_id$|_code$|_type$|_name$|posts_to|sales_tax|trans_type|_date$|_time$|_flag$|number|sys|class$|basis$|needs)','','g') ~* '(?<!((^|_)[[:alnum:]]{0,2}|(^|_)[bcdfghjklmnpqrsztvwxz]{0,4}|s))s(_|$)' OR column_name~*'(ids|codes)$') AND column_name!~*'(key|value|group)$' THEN 'Perhaps plural' ELSE 'Perhaps singular' END AS comment_about_the_column_name
FROM columns),
plural_singular_evaluation AS 
(SELECT table_schema, table_name, table_type, column_name, column_type, comment_about_the_column_name,
CASE WHEN comment_about_the_column_name='Perhaps plural' AND column_type!~*'(array|json|xml|int|numeric|float)' THEN 'Perhaps should be singular'
WHEN comment_about_the_column_name='Perhaps singular' AND column_type~*'(array|json|xml)' THEN 'Perhaps should be plural'
ELSE 'OK' END AS evaluation
FROM plural_or_singular)
SELECT table_type, comment_about_the_column_name, evaluation, Count(*) AS nr_of_columns
FROM plural_singular_evaluation
GROUP BY ROLLUP (table_type, comment_about_the_column_name, evaluation)
ORDER BY table_type, Count(*) DESC, comment_about_the_column_name, evaluation;

Collections where the query belongs to

Collection nameCollection description
Find problems about namesA selection of queries that return information about the names of database objects. Contains all the types of queries - problem detection, software measure, and general overview.
Lexicon bad smells and linguistic antipatternsQueries made to find the occurrences of lexicon bad smells and linguistic antipatterns

Categories where the query belongs to

Category nameCategory description
InconsistenciesQueries of this catergory provide information about inconsistencies of solving the same problem in different places.
NamingQueries of this category provide information about the style of naming.

Reference materials for further reading

Reference
Linguistic antipatterns "D.1 Says one but contains many" and "E.1 Says many but contains one": Arnaoudova, V., Di Penta, M., Antoniol, G., 2016. Linguistic antipatterns: What they are and how developers perceive them. Empirical Software Engineering, 21(1), pp.104-158.

The list of all the queries