Find views that use a function to get data from another table.
Notes
In the returned subquery of view/materialized view and in the body of routine 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. There could be multiple routines with the same name but with different parameters in the same schema (overloading). Thus, for the unique identification of the routine it is necessary to present also its parameters in addition to the schema name and routine name.
Type
Problem detection (Each row in the result could represent a flaw in the design)
Use joins instead of the function to get better performance.
Data Source
INFORMATION_SCHEMA+system catalog
SQL Query
WITH select_routines AS (SELECT
pg_proc.oid,
pg_namespace.nspname AS specific_schema,
pg_proc.proname AS routine_name,
pg_proc.proname || '_' || pg_proc.oid AS specific_name,
pg_get_function_identity_arguments(pg_proc.oid) AS parameters,
CASE WHEN pg_proc.prokind='f' THEN 'FUNCTION'
WHEN pg_proc.prokind='p' THEN 'PROCEDURE'
WHEN pg_proc.prokind='w' THEN 'WINDOW FUNCTION' END AS routine_type,
regexp_replace(pg_get_functiondef(pg_proc.oid),'[\r\n]',' ','g') AS routine_src,
pg_language.lanname AS routine_language
FROM
pg_catalog.pg_proc,
pg_catalog.pg_namespace,
pg_catalog.pg_language
WHERE
pg_proc.pronamespace = pg_namespace.oid
AND pg_proc.prolang = pg_language.oid
AND pg_proc.prokind<>'a'
AND pg_get_functiondef(pg_proc.oid)~*'SELECT[[:space:]].*FROM[[:space:]]'
AND pg_namespace.nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL))
SELECT table_schema AS schema,
table_name AS view,
'VIEW' AS type,
regexp_replace(view_definition,'[\r\n]',' ','g') AS view_definition,
specific_schema AS routine_schema,
routine_name,
parameters,
routine_type,
routine_src,
routine_language
FROM Information_schema.views INNER JOIN Information_schema.view_routine_usage USING (table_schema, table_name)
INNER JOIN select_routines USING (specific_schema, specific_name)
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,
specific_schema,
routine_name,
pg_get_function_identity_arguments(oid) AS parameters,
routine_type,
routine_src,
routine_language
FROM pg_catalog.pg_matviews, select_routines
WHERE definition LIKE '% ' || routine_name || '(%'
ORDER BY schema, view;
Collections
This query belongs to the following collections:
Name
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 .
Categories
This query is classified under the following categories:
Name
Description
Derived tables
Queries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.
Performance
Queries of this category provide information about indexes in a database.
User-defined routines
Queries of this category provide information about the user-defined routines