Query goal: | Find columns of derived tables (i.e., views and materialized views) where in the creation statement of the table the name of the column has not been specified, i.e., it is generated by the system. |
Notes about the query: | The query looks the source to find a pattern where a function has been used in the SELECT clause but the resulting column name has probably been system-defined. The query considers only some of the most popular functions. |
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 |
Data source: | system catalog only |
SQL query: | Click on query to copy it
WITH derived_tables AS ( SELECT c.oid, n.nspname AS schema_name, c.relname AS table_name, CASE WHEN c.relkind='v' THEN 'VIEW' WHEN c.relkind='m' THEN 'MATERIALIZED VIEW' END AS table_type, regexp_replace(pg_get_viewdef(c.oid),'[\r\n]','<br>','g') AS view_src, pg_get_viewdef(c.oid) AS view_src_original FROM pg_attribute at INNER JOIN pg_class c ON at.attrelid=c.oid INNER JOIN pg_namespace AS n ON n.oid=c.relnamespace INNER JOIN pg_authid AS a ON n.nspowner=a.oid WHERE (nspname='public' OR rolname<>'postgres') AND c.relkind IN ('v','m') AND at.attisdropped='f' AND at.attnum>0 ) SELECT schema_name, table_name, table_type, view_src FROM derived_tables WHERE view_src_original~*'localtimestamp[^,]*[[:space:]]+AS[[:space:]]+"localtimestamp' OR view_src_original~*'curren_timestamp[^,]*[[:space:]]+AS[[:space:]]+"current_timestamp' OR view_src_original~*'now[^,]*[[:space:]]+AS[[:space:]]+"now' OR view_src_original~*'min[^,]*[[:space:]]+AS[[:space:]]+"min' OR view_src_original~*'max[^,]*[[:space:]]+AS[[:space:]]+"max' OR view_src_original~*'count[^,]*[[:space:]]+AS[[:space:]]+"count' OR view_src_original~*'sum[^,]*[[:space:]]+AS[[:space:]]+"sum' OR view_src_original~*'avg[^,]*[[:space:]]+AS[[:space:]]+"avg' OR view_src_original~*'upper[^,]*[[:space:]]+AS[[:space:]]+"upper' OR view_src_original~*'lower[^,]*[[:space:]]+AS[[:space:]]+"lower' ORDER BY schema_name, table_name; |
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 data management | Queries of this category provide information about the means that have been used to make the use or management of database more comfortable and thus, more efficient. |
Derived tables | Queries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer. |
Naming | Queries of this category provide information about the style of naming. |