Query goal: | Find materialized views with exactly the same subquery. There should not be multiple materialized views with 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 materialized 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 redundant materialized views. |
Data source: | system catalog only |
SQL query: | Click on query to copy it
SELECT regexp_replace(definition,'[\r\n]','<br>','g') AS definition, mat_views, number_of_materialized_views FROM (SELECT definition, string_agg(schemaname || '.'|| matviewname,';<br>' ORDER BY schemaname || '.'|| matviewname) AS mat_views, Count(*) AS number_of_materialized_views FROM pg_catalog.pg_matviews GROUP BY definition HAVING Count(*)>1) AS duplicate_mat_views ORDER BY number_of_materialized_views DESC; |
SQL query | Description |
---|---|
WITH duplicate_mat_views AS (SELECT definition AS mat_view_definition, array_agg(schemaname || '.'|| matviewname) AS mat_views FROM pg_catalog.pg_matviews GROUP BY definition HAVING Count(*)>1) SELECT format('DROP MATERIALIZED VIEW %1$s;', unnest(mat_views)) AS statements FROM duplicate_mat_views ORDER BY mat_view_definition; | Drop the materialized view. One of the materialized views must stay in place. |
Collection name | Collection 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 . |
Category name | Category 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. |
Data redundancy | Queries of this category provide information about possible data redunancy. |
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. |
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) |