Goal Find derived tables (views and materialized views) that sort rows based on random values. This can be used to find a random subset of rows. It is a computationally expensive operation.
Notes In the returned subquery of view/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.
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
Fixing Suggestion Bill Karwin in his book of SQL database design antipatterns offers various alternatives for finding a random subset of rows.
Data Source INFORMATION_SCHEMA+system catalog
SQL Query
SELECT
table_schema,
table_name,
type,
regexp_replace(view_definition,'[\r\n]','
','g') AS view_definition FROM (SELECT views.table_schema, views.table_name, 'VIEW' AS type, views.view_definition FROM information_schema.views WHERE 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) UNION SELECT schemaname, matviewname, 'MATERIALIZED VIEW' AS type, regexp_replace(definition,'[\r\n]','
','g') AS definition FROM pg_catalog.pg_matviews) AS foo WHERE view_definition ~*'order[[:space:]]+by[[:space:]]+[(]random[(][)][)]' ORDER BY table_schema, table_name;
Categories

This query is classified under the following categories:

NameDescription
Derived tablesQueries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.
PerformanceQueries of this category provide information about indexes in a database.

Further reading and related materials:

Reference
This is one of the antipatterns from the Bill Karwin's book of SQL antipatterns. See Chapter 16: Random Selection.