The list of all the queries

Duplicate views

Query goal: Find views with exactly the same subquery. There should not be multiple views with exactly the same subquery. Do remember that the same task can be solved in SQL usually in multiple different ways. Thus, the exact copies are not the only possible duplication.
Notes about the query: In the returned subquery of view the query replaces each newline character with the line break (br) tag for the better readability in case the query result is displayed in a web browser. In case of the string_agg function, the line break (br) tag is used as a part of the separator for the better readability in case the query result is displayed in a web browser.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: High (Few or no false-positive results)
Query license: MIT License
Fixing suggestion: All but one are redundant. Drop the redundant views.
Data source: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

SELECT regexp_replace(view_definition,'[\r\n]','<br>','g') AS view_definition, views, number_of_views
FROM (SELECT  view_definition, string_agg(table_schema || '.'|| table_name,';<br>' ORDER BY table_schema || '.'|| table_name) AS views, Count(*) AS number_of_views
FROM  information_schema.views
WHERE 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)
GROUP BY view_definition
HAVING Count(*)>1) AS duplicate_views
ORDER BY number_of_views DESC;

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

SQL queryDescription
WITH duplicate_views AS (SELECT  view_definition,  array_agg(table_schema || '.' || table_name) AS view_array
FROM  information_schema.views
WHERE 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)
GROUP BY view_definition
HAVING Count(*)>1)
SELECT format('DROP VIEW %1$s;', unnest(view_array)) AS statements
FROM duplicate_views
ORDER BY view_definition;
Drop the view. One of the views must stay in place.

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
Comfortability of database evolutionQueries of this category provide information about the means that influence database evolution.
Derived tablesQueries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.
Duplication of implementation elementsQueries of this catergory provide information about the duplication of the database objects.

Reference materials for further reading

Reference
https://refactoring.guru/smells/alternative-classes-with-different-interfaces
https://refactoring.guru/smells/duplicate-code
The corresponding code smell in case of cleaning code is "G5: Duplication". (Robert C. Martin, Clean Code)

The list of all the queries