The list of all the queries

Duplicate stored generated base table columns

Query goal: Find base tables that have more than one stored generated column with the same expression. The support of generated columns was added to PostgreSQL 12. 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.
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 stored generated columns.
Data source: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

SELECT table_schema, table_name, generation_expression, Count(*) AS number_of_occurrences, string_agg(column_name, ';<br>' ORDER BY column_name) AS columns
FROM INFORMATION_SCHEMA.columns
WHERE (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') 
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) 
AND is_generated='ALWAYS'
GROUP BY table_schema, table_name, generation_expression
HAVING Count(*)>1
ORDER BY Count(*)>1 DESC, table_schema, table_name;

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

SQL queryDescription
WITH duplicate_columns AS (SELECT table_schema, table_name, generation_expression, array_agg(column_name) AS columns
FROM INFORMATION_SCHEMA.columns
WHERE (table_schema, table_name) IN (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables WHERE table_type='BASE TABLE') 
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) 
AND is_generated='ALWAYS'
GROUP BY table_schema, table_name, generation_expression
HAVING Count(*)>1)
SELECT DISTINCT format('ALTER TABLE %1$I.%2$I DROP COLUMN %3$I;', table_schema, table_name, unnest(columns)) AS statements
FROM duplicate_columns 
ORDER BY statements;
Drop the column. One of the columns 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
Duplication of implementation elementsQueries of this catergory provide information about the duplication of the database objects.
Generated columnsQueries of this category provide information about generated stored base table columns.

The list of all the queries