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
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.
Type
Problem detection (Each row in the result could represent a flaw in the design)
All but one are redundant. Drop the redundant views.
Data Source
INFORMATION_SCHEMA only
SQL Query
SELECT regexp_replace(view_definition,'[\r\n]',' ','g') AS view_definition, views, number_of_views
FROM (SELECT view_definition, string_agg(table_schema || '.'|| table_name,'; ' 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 that help generate fixes for the identified problem.
SQL Query to Generate Fix
Description
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
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 database evolution
Queries of this category provide information about the means that influence database evolution.
Derived tables
Queries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.
Duplication of implementation elements
Queries of this catergory provide information about the duplication of the database objects.