Query goal: | Find for each base table the list of routines (functions and procedures) that refer to the base table. If the database is used through the public database interface (virtual data layer), then, ideally, each table is referred from at least one routine. |
Notes about the query: | The query uses the information_schema view routine_column_usage that was added to PostgreSQL 14. The view contains only information about routines that are written in SQL language and have the SQL-standard body. In case of the string_agg function, the line break (br) tag is used as a part of the separator 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. |
Query type: | General (Overview of some aspect of the database.) |
Query license: | MIT License |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
WITH routine_table AS (SELECT DISTINCT t.table_schema, t.table_name, rtu.routine_schema, rtu.routine_name, pg_get_function_identity_arguments(translate(substring(rtu.specific_name,'_[0-9]+$'),'_','')::int::oid) AS parameters, r.routine_type FROM information_schema.tables AS t LEFT JOIN information_schema.routine_column_usage AS rtu USING (table_schema, table_name) LEFT JOIN information_schema.routines AS r USING (specific_schema, specific_name) WHERE t.table_type = 'BASE TABLE' AND t.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)) SELECT table_schema, table_name, string_agg(routine_schema || '.' || routine_name || '(' || parameters || ') (' || routine_type || ')', ';<br>' ORDER BY routine_schema, routine_name, parameters) AS list_of_routines, Count(routine_schema) AS number_of_routines FROM routine_table GROUP BY table_schema, table_name ORDER BY Count(routine_schema) DESC, table_schema, table_name; |
Collection name | Collection description |
---|---|
Find problems by overview | Queries that results point to different aspects of database that might have problems. A human reviewer has to decide based on the results as to whether there are problems or not . |
Category name | Category description |
---|---|
Does not work in some earlier PostgreSQL version | Queries of this category provide information that was not available in some earlier PostgreSQL version |
User-defined routines | Queries of this category provide information about the user-defined routines |