Query goal: | Find base tables where more than one column gets the default value by using the sequence generator mechanism. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | Low (Many false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Perhaps some of these columns are unnecessary or do not need a default value. |
Data source: | INFORMATION_SCHEMA only |
SQL query: | Click on query to copy it
WITH defs AS (SELECT c.table_schema, t.table_type, c.table_name, c.column_name, c.data_type, c.domain_schema, c.domain_name, coalesce(c.column_default, domain_default) AS default_value, CASE WHEN c.column_default IS NOT NULL THEN 'Column default' ELSE 'Domain default' END AS default_type FROM information_schema.columns AS c LEFT JOIN information_schema.domains d USING (domain_schema, domain_name) INNER JOIN INFORMATION_SCHEMA.tables AS t USING (table_schema, table_name) WHERE c.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 (column_default IS NOT NULL OR domain_default IS NOT NULL)) SELECT table_schema, table_name, table_type, Count(*) AS nr_of_surrogates, string_agg(column_name || '(' || data_type || ')' || ' ' || default_value,';<br>' ORDER BY table_schema, table_name) AS columns FROM defs WHERE default_value~*'.*nextval[(]' GROUP BY table_schema, table_name, table_type HAVING Count(*)>1 ORDER BY Count(*) DESC, table_schema, table_name; |
Collection name | Collection description |
---|---|
Find problems about base tables | A selection of queries that return information about the data types, field sizes, default values as well as general structure of base tables. Contains all the types of queries - problem detection, software measure, and general overview |
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 |
---|---|
Default value | Queries of this catergory provide information about the use of default values. |
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. |
Uniqueness | Queries of this category provide information about uniqueness constraints (PRIMARY KEY, UNIQUE, EXCLUDE) as well as unique indexes. |