Goal Find, based on default values, cases where a multi-valued attribute in a conceptual data model is implemented as a textual column of a base table or a foreign table. Expected values in the column are strings that contain attribute values, separated by commas or other separation characters.
Notes The query finds default values that are associated directly with a base table column as well as default values that are specified through a domain. The query does not find default values of domains that are not associated with any table.
Type Problem detection (Each row in the result could represent a flaw in the design)
Reliability Medium (Medium number of false-positive results)
License MIT License
Data Source INFORMATION_SCHEMA only
SQL Query
SELECT c.table_schema, t.table_type, c.table_name, c.column_name,  c.data_type, c.domain_schema, c.domain_name, c.column_default, domain_default
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)
AND c.data_type~*'(char|text)' 
AND (c.column_default~'(,|;).+'
OR d.domain_default~'(,|;).+')
ORDER BY t.table_type, c.table_schema, c.table_name, c.ordinal_position;

Collections

This query belongs to the following collections:

NameDescription
Find problems about base tablesA 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 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

This query is classified under the following categories:

NameDescription
Database design antipatternsQueries of this category provide information about possible occurrences of SQL database design antipatterns.
Default valueQueries of this catergory provide information about the use of default values.
Structure of base tablesQueries of this category provide information about the structuring of base tables at the database conceptual level

Further reading and related materials:

Reference
This is one of the antipatterns from the Bill Karwin's book of SQL antipatterns. See Chapter 2: Jaywalking.
Smell "Compund attribute": Sharma, T., Fragkoulis, M., Rizou, S., Bruntink, M. and Spinellis, D.: Smelly relations: measuring and understanding database schema quality. In: Proceedings of the 40th International Conference on Software Engineering: Software Engineering in Practice, pp. 55-64. ACM, (2018).
Factor, P.: SQL Code Smells. Redgate, http://assets.red-gate.com/community/books/sql-code-smells.pdf, last accessed 2019/12/29 (Packing lists, complex data, or other multivariate attributes into a table column)