Query goal: | Do not create unnecessary sequence generators. |
Notes about the query: | The query uses sequence names to identify potential duplicates. For instance, after executing the statements CREATE SEQUENCE seq_test_seq_test_id_seq; CREATE TABLE Seq_test(seq_test_id SERIAL); there are two sequences - seq_test_seq_test_id_seq and seq_test_seq_test_id_seq1 in the database. The sequence seq_test_seq_test_id_seq is redundant because the use of SERIAL notation will cause automatic creation of a sequence. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | Medium (Medium number of false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Drop the redundant sequences. |
Data source: | INFORMATION_SCHEMA only |
SQL query: | Click on query to copy it
WITH seqs AS (SELECT sequence_schema, regexp_replace(sequence_name,'[0-9]','','g') AS sequence_name_without_numbers FROM information_schema.sequences WHERE sequence_schema NOT IN (SELECT schema_name FROM information_schema.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL)) SELECT sequence_schema, sequence_name_without_numbers, Count(*) AS number_of_sequences FROM seqs GROUP BY sequence_schema, sequence_name_without_numbers HAVING Count(*)>1 ORDER BY sequence_schema, sequence_name_without_numbers, Count(*) DESC; |
SQL query | Description |
---|---|
WITH seqs AS (SELECT sequence_schema, regexp_replace(sequence_name,'[0-9]','','g') AS sequence_name_without_numbers, sequence_name FROM information_schema.sequences WHERE sequence_schema NOT IN (SELECT schema_name FROM information_schema.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL)), duplicate_seqs AS (SELECT sequence_schema, sequence_name_without_numbers, array_agg(sequence_schema || '.' || sequence_name) AS seqs_array FROM seqs GROUP BY sequence_schema, sequence_name_without_numbers HAVING Count(*)>1) SELECT format ('DROP SEQUENCE %1$s;', unnest(seqs_array)) AS statements FROM duplicate_seqs ORDER BY sequence_schema, sequence_name_without_numbers; | Drop the sequence. Do not execute all the statements - make sure that you drop only these that are indeed duplicates. |
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 database evolution | Queries of this category provide information about the means that influence database evolution. |
Duplication of implementation elements | Queries of this catergory provide information about the duplication of the database objects. |
Sequence generators | Queries of this category provide information about sequence generators and their usage. |
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) |