c77_dep/c77_dep--1.0.0.sql
2025-03-30 12:27:52 -05:00

960 lines
44 KiB
PL/PgSQL

/* ================================================================
* c77_dep extension version 1.0.0
* PostgreSQL Database Dependency Mapping Tool
*
* This extension provides tools for analyzing and visualizing
* dependencies between database objects.
* ================================================================
*/
-- Complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION c77_dep" to load this file. \quit
-- Set up the schema
-- Uncomment if you want to use a dedicated schema instead of public
-- CREATE SCHEMA IF NOT EXISTS c77_dep;
-- Core dependency mapping view (base version)
CREATE OR REPLACE VIEW public.c77_dep_dependencies_map
AS
WITH RECURSIVE ctedepends AS (
SELECT DISTINCT 1 AS depth,
source_ns.nspname AS source_schema,
source_table.relname AS source_rel,
source_ns.nspname AS inter_schema,
source_table.relname AS inter_rel,
dependent_ns.nspname AS dependent_schema,
dependent_view.relname AS dependent_rel
FROM pg_depend
JOIN pg_rewrite ON pg_depend.objid = pg_rewrite.oid
JOIN pg_class dependent_view ON dependent_view.oid = pg_rewrite.ev_class
JOIN pg_class source_table ON source_table.oid = pg_depend.refobjid
JOIN pg_namespace dependent_ns ON dependent_ns.oid = dependent_view.relnamespace
JOIN pg_namespace source_ns ON source_ns.oid = source_table.relnamespace
WHERE NOT (dependent_ns.nspname = source_ns.nspname AND dependent_view.relname = source_table.relname)
UNION
SELECT DISTINCT cd.depth + 1 AS depth,
cd.source_schema,
cd.source_rel,
source_ns.nspname AS inter_schema,
source_table.relname AS inter_rel,
dependent_ns.nspname AS dependent_schema,
dependent_view.relname AS dependent_rel
FROM pg_depend
JOIN pg_rewrite ON pg_depend.objid = pg_rewrite.oid
JOIN pg_class dependent_view ON pg_rewrite.ev_class = dependent_view.oid
JOIN pg_class source_table ON pg_depend.refobjid = source_table.oid
JOIN pg_namespace dependent_ns ON dependent_ns.oid = dependent_view.relnamespace
JOIN pg_namespace source_ns ON source_ns.oid = source_table.relnamespace
JOIN ctedepends cd ON cd.dependent_schema = source_ns.nspname AND cd.dependent_rel = source_table.relname AND NOT (dependent_ns.nspname = cd.dependent_schema AND dependent_view.relname = cd.dependent_rel)
), ctedependents AS (
SELECT x.source,
string_agg(x.dependent, ' | '::text) AS dependents,
count(*) AS deps
FROM ( SELECT DISTINCT (ctedepends.source_schema::text || '.'::text) || ctedepends.source_rel::text AS source,
(ctedepends.dependent_schema::text || '.'::text) || ctedepends.dependent_rel::text AS dependent
FROM ctedepends
WHERE 1 = ctedepends.depth) x
GROUP BY x.source
ORDER BY x.source
), cteadddependents AS (
SELECT x.source,
string_agg(DISTINCT x.dependent, ' | '::text) AS dependents,
count(*) AS deps
FROM ( SELECT DISTINCT (dep_1.source_schema::text || '.'::text) || dep_1.source_rel::text AS source,
(dep_1.dependent_schema::text || '.'::text) || dep_1.dependent_rel::text AS dependent
FROM ctedepends dep_1
JOIN ctedependents deps ON deps.source = ((dep_1.source_schema::text || '.'::text) || dep_1.source_rel::text)
WHERE 1 < dep_1.depth AND 0 = POSITION((((dep_1.dependent_schema::text || '.'::text) || dep_1.dependent_rel::text) || ' |'::text) IN (deps.dependents || ' |'::text))) x
GROUP BY x.source
ORDER BY x.source
), cterequires AS (
SELECT DISTINCT ns_r.nspname AS basensp,
cl_r.relname AS basename,
ns_r.nspname AS relnsp,
cl_r.relname,
ns_d.nspname AS reqnsp,
cl_d.relname AS reqname,
1 AS depth
FROM pg_rewrite r
JOIN pg_class cl_r ON cl_r.oid = r.ev_class
JOIN pg_namespace ns_r ON ns_r.oid = cl_r.relnamespace
JOIN pg_depend d ON d.objid = r.oid
JOIN pg_class cl_d ON cl_d.oid = d.refobjid
JOIN pg_namespace ns_d ON ns_d.oid = cl_d.relnamespace
WHERE (cl_d.relkind = ANY (ARRAY['r'::"char", 'm'::"char", 'v'::"char"])) AND (ns_r.nspname <> ALL (ARRAY['information_schema'::name, 'pg_catalog'::name])) AND ns_r.nspname !~~ 'pg_toast%'::text AND ((ns_r.nspname::text || '.'::text) || cl_r.relname::text) <> ((ns_d.nspname::text || '.'::text) || cl_d.relname::text)
UNION
SELECT cterequires.basensp,
cterequires.basename,
ns_r.nspname AS relnsp,
cl_r.relname,
ns_d.nspname AS reqnsp,
cl_d.relname AS reqname,
cterequires.depth + 1 AS depth
FROM pg_rewrite r
JOIN pg_class cl_r ON cl_r.oid = r.ev_class
JOIN pg_namespace ns_r ON ns_r.oid = cl_r.relnamespace
JOIN pg_depend d ON d.objid = r.oid
JOIN pg_class cl_d ON cl_d.oid = d.refobjid
JOIN pg_namespace ns_d ON ns_d.oid = cl_d.relnamespace
JOIN cterequires ON cterequires.reqnsp = ns_r.nspname AND cterequires.reqname = cl_r.relname AND NOT (cterequires.reqnsp = ns_d.nspname AND cterequires.reqname = cl_d.relname)
WHERE ((ns_r.nspname::text || '.'::text) || cl_r.relname::text) <> ((ns_d.nspname::text || '.'::text) || cl_d.relname::text) AND (cl_d.relkind = ANY (ARRAY['r'::"char", 'm'::"char", 'v'::"char"])) AND ns_r.nspname !~~ 'pg_toast%'::text AND (ns_r.nspname <> ALL (ARRAY['information_schema'::name, 'pg_catalog'::name]))
), cterequirements AS (
SELECT DISTINCT (cterequires.basensp::text || '.'::text) || cterequires.basename::text AS rel,
count(*) AS reqs,
string_agg((cterequires.reqnsp::text || '.'::text) || cterequires.reqname::text, ' | '::text) AS reqlist
FROM cterequires
WHERE 1 = cterequires.depth
GROUP BY ((cterequires.basensp::text || '.'::text) || cterequires.basename::text)
), cteaddrequirements AS (
SELECT DISTINCT (cterequires.basensp::text || '.'::text) || cterequires.basename::text AS rel,
count(*) AS addreqs,
string_agg(DISTINCT (cterequires.reqnsp::text || '.'::text) || cterequires.reqname::text, ' | '::text) AS addreqlist
FROM cterequires
JOIN cterequirements ON cterequirements.rel = ((cterequires.basensp::text || '.'::text) || cterequires.basename::text)
WHERE 1 < cterequires.depth AND 0 = POSITION((((cterequires.reqnsp::text || '.'::text) || cterequires.reqname::text) || ' |'::text) IN (cterequirements.reqlist || ' |'::text))
GROUP BY ((cterequires.basensp::text || '.'::text) || cterequires.basename::text)
)
SELECT (nsp.nspname::text || '.'::text) || cls.relname::text AS relation,
CASE cls.relkind
WHEN 'r'::"char" THEN 'TABLE'::text
WHEN 'v'::"char" THEN 'VIEW'::text
WHEN 'm'::"char" THEN 'MATV'::text
WHEN 'i'::"char" THEN 'INDEX'::text
WHEN 'S'::"char" THEN 'SEQUENCE'::text
WHEN 'c'::"char" THEN 'TYPE'::text
ELSE cls.relkind::text
END AS object_type,
rol.rolname AS owner,
COALESCE(dep.deps, 0::bigint) AS deps,
CASE
WHEN ''::text <> depadd.dependents THEN 1 + (length(depadd.dependents) - length(replace(depadd.dependents, '|'::text, ''::text)))
ELSE 0
END AS add_deps,
COALESCE(req.reqs, 0::bigint) AS reqs,
CASE
WHEN ''::text <> addreq.addreqlist THEN 1 + (length(addreq.addreqlist) - length(replace(addreq.addreqlist, '|'::text, ''::text)))
ELSE 0
END AS add_reqs,
COALESCE(dep.dependents, ''::text) AS dependents,
COALESCE(depadd.dependents, ''::text) AS add_dependents,
COALESCE(req.reqlist, ''::text) AS requirements,
COALESCE(addreq.addreqlist, ''::text) AS add_requirements
FROM pg_class cls
JOIN pg_namespace nsp ON nsp.oid = cls.relnamespace
JOIN pg_roles rol ON rol.oid = cls.relowner
LEFT JOIN ctedependents dep ON dep.source = ((nsp.nspname::text || '.'::text) || cls.relname::text)
LEFT JOIN cteadddependents depadd ON depadd.source = ((nsp.nspname::text || '.'::text) || cls.relname::text)
LEFT JOIN cterequirements req ON req.rel = ((nsp.nspname::text || '.'::text) || cls.relname::text)
LEFT JOIN cteaddrequirements addreq ON addreq.rel = ((nsp.nspname::text || '.'::text) || cls.relname::text)
WHERE (cls.relkind = ANY (ARRAY['r'::"char", 'v'::"char", 'm'::"char"])) AND nsp.nspname !~~ 'pg_toast%'::text AND (nsp.nspname <> ALL (ARRAY['information_schema'::name, 'pg_catalog'::name]))
ORDER BY nsp.nspname, cls.relname;
COMMENT ON VIEW public.c77_dep_dependencies_map IS 'Maps dependencies between database objects (tables, views, materialized views)';
-- Enhanced dependency map with foreign tables
CREATE OR REPLACE VIEW public.c77_dep_dependencies_map_with_foreign
AS
WITH RECURSIVE ctedepends AS (
SELECT DISTINCT 1 AS depth,
source_ns.nspname AS source_schema,
source_table.relname AS source_rel,
source_ns.nspname AS inter_schema,
source_table.relname AS inter_rel,
dependent_ns.nspname AS dependent_schema,
dependent_view.relname AS dependent_rel
FROM pg_depend
JOIN pg_rewrite ON pg_depend.objid = pg_rewrite.oid
JOIN pg_class dependent_view ON dependent_view.oid = pg_rewrite.ev_class
JOIN pg_class source_table ON source_table.oid = pg_depend.refobjid
JOIN pg_namespace dependent_ns ON dependent_ns.oid = dependent_view.relnamespace
JOIN pg_namespace source_ns ON source_ns.oid = source_table.relnamespace
WHERE NOT (dependent_ns.nspname = source_ns.nspname AND dependent_view.relname = source_table.relname)
UNION
SELECT DISTINCT cd.depth + 1 AS depth,
cd.source_schema,
cd.source_rel,
source_ns.nspname AS inter_schema,
source_table.relname AS inter_rel,
dependent_ns.nspname AS dependent_schema,
dependent_view.relname AS dependent_rel
FROM pg_depend
JOIN pg_rewrite ON pg_depend.objid = pg_rewrite.oid
JOIN pg_class dependent_view ON pg_rewrite.ev_class = dependent_view.oid
JOIN pg_class source_table ON pg_depend.refobjid = source_table.oid
JOIN pg_namespace dependent_ns ON dependent_ns.oid = dependent_view.relnamespace
JOIN pg_namespace source_ns ON source_ns.oid = source_table.relnamespace
JOIN ctedepends cd ON cd.dependent_schema = source_ns.nspname AND cd.dependent_rel = source_table.relname AND NOT (dependent_ns.nspname = cd.dependent_schema AND dependent_view.relname = cd.dependent_rel)
), ctedependents AS (
SELECT x.source,
string_agg(x.dependent, ' | '::text) AS dependents,
count(*) AS deps
FROM ( SELECT DISTINCT (ctedepends.source_schema::text || '.'::text) || ctedepends.source_rel::text AS source,
(ctedepends.dependent_schema::text || '.'::text) || ctedepends.dependent_rel::text AS dependent
FROM ctedepends
WHERE 1 = ctedepends.depth) x
GROUP BY x.source
ORDER BY x.source
), cteadddependents AS (
SELECT x.source,
string_agg(DISTINCT x.dependent, ' | '::text) AS dependents,
count(*) AS deps
FROM ( SELECT DISTINCT (dep_1.source_schema::text || '.'::text) || dep_1.source_rel::text AS source,
(dep_1.dependent_schema::text || '.'::text) || dep_1.dependent_rel::text AS dependent
FROM ctedepends dep_1
JOIN ctedependents deps ON deps.source = ((dep_1.source_schema::text || '.'::text) || dep_1.source_rel::text)
WHERE 1 < dep_1.depth AND 0 = POSITION((((dep_1.dependent_schema::text || '.'::text) || dep_1.dependent_rel::text) || ' |'::text) IN (deps.dependents || ' |'::text))) x
GROUP BY x.source
ORDER BY x.source
), cterequires AS (
SELECT DISTINCT ns_r.nspname AS basensp,
cl_r.relname AS basename,
ns_r.nspname AS relnsp,
cl_r.relname,
ns_d.nspname AS reqnsp,
cl_d.relname AS reqname,
1 AS depth
FROM pg_rewrite r
JOIN pg_class cl_r ON cl_r.oid = r.ev_class
JOIN pg_namespace ns_r ON ns_r.oid = cl_r.relnamespace
JOIN pg_depend d ON d.objid = r.oid
JOIN pg_class cl_d ON cl_d.oid = d.refobjid
JOIN pg_namespace ns_d ON ns_d.oid = cl_d.relnamespace
WHERE (cl_d.relkind = ANY (ARRAY['r'::"char", 'm'::"char", 'v'::"char", 'f'::"char"])) AND (ns_r.nspname <> ALL (ARRAY['information_schema'::name, 'pg_catalog'::name])) AND ns_r.nspname !~~ 'pg_toast%'::text AND ((ns_r.nspname::text || '.'::text) || cl_r.relname::text) <> ((ns_d.nspname::text || '.'::text) || cl_d.relname::text)
UNION
SELECT cterequires.basensp,
cterequires.basename,
ns_r.nspname AS relnsp,
cl_r.relname,
ns_d.nspname AS reqnsp,
cl_d.relname AS reqname,
cterequires.depth + 1 AS depth
FROM pg_rewrite r
JOIN pg_class cl_r ON cl_r.oid = r.ev_class
JOIN pg_namespace ns_r ON ns_r.oid = cl_r.relnamespace
JOIN pg_depend d ON d.objid = r.oid
JOIN pg_class cl_d ON cl_d.oid = d.refobjid
JOIN pg_namespace ns_d ON ns_d.oid = cl_d.relnamespace
JOIN cterequires ON cterequires.reqnsp = ns_r.nspname AND cterequires.reqname = cl_r.relname AND NOT (cterequires.reqnsp = ns_d.nspname AND cterequires.reqname = cl_d.relname)
WHERE ((ns_r.nspname::text || '.'::text) || cl_r.relname::text) <> ((ns_d.nspname::text || '.'::text) || cl_d.relname::text) AND (cl_d.relkind = ANY (ARRAY['r'::"char", 'm'::"char", 'v'::"char", 'f'::"char"])) AND ns_r.nspname !~~ 'pg_toast%'::text AND (ns_r.nspname <> ALL (ARRAY['information_schema'::name, 'pg_catalog'::name]))
), cterequirements AS (
SELECT DISTINCT (cterequires.basensp::text || '.'::text) || cterequires.basename::text AS rel,
count(*) AS reqs,
string_agg((cterequires.reqnsp::text || '.'::text) || cterequires.reqname::text, ' | '::text) AS reqlist
FROM cterequires
WHERE 1 = cterequires.depth
GROUP BY ((cterequires.basensp::text || '.'::text) || cterequires.basename::text)
), cteaddrequirements AS (
SELECT DISTINCT (cterequires.basensp::text || '.'::text) || cterequires.basename::text AS rel,
count(*) AS addreqs,
string_agg(DISTINCT (cterequires.reqnsp::text || '.'::text) || cterequires.reqname::text, ' | '::text) AS addreqlist
FROM cterequires
JOIN cterequirements ON cterequirements.rel = ((cterequires.basensp::text || '.'::text) || cterequires.basename::text)
WHERE 1 < cterequires.depth AND 0 = POSITION((((cterequires.reqnsp::text || '.'::text) || cterequires.reqname::text) || ' |'::text) IN (cterequirements.reqlist || ' |'::text))
GROUP BY ((cterequires.basensp::text || '.'::text) || cterequires.basename::text)
)
SELECT (nsp.nspname::text || '.'::text) || cls.relname::text AS relation,
CASE cls.relkind
WHEN 'r'::"char" THEN 'TABLE'::text
WHEN 'v'::"char" THEN 'VIEW'::text
WHEN 'm'::"char" THEN 'MATV'::text
WHEN 'f'::"char" THEN 'FOREIGN TABLE'::text
WHEN 'i'::"char" THEN 'INDEX'::text
WHEN 'S'::"char" THEN 'SEQUENCE'::text
WHEN 'c'::"char" THEN 'TYPE'::text
ELSE cls.relkind::text
END AS object_type,
rol.rolname AS owner,
COALESCE(dep.deps, 0::bigint) AS deps,
CASE
WHEN ''::text <> depadd.dependents THEN 1 + (length(depadd.dependents) - length(replace(depadd.dependents, '|'::text, ''::text)))
ELSE 0
END AS add_deps,
COALESCE(req.reqs, 0::bigint) AS reqs,
CASE
WHEN ''::text <> addreq.addreqlist THEN 1 + (length(addreq.addreqlist) - length(replace(addreq.addreqlist, '|'::text, ''::text)))
ELSE 0
END AS add_reqs,
COALESCE(dep.dependents, ''::text) AS dependents,
COALESCE(depadd.dependents, ''::text) AS add_dependents,
COALESCE(req.reqlist, ''::text) AS requirements,
COALESCE(addreq.addreqlist, ''::text) AS add_requirements
FROM pg_class cls
JOIN pg_namespace nsp ON nsp.oid = cls.relnamespace
JOIN pg_roles rol ON rol.oid = cls.relowner
LEFT JOIN ctedependents dep ON dep.source = ((nsp.nspname::text || '.'::text) || cls.relname::text)
LEFT JOIN cteadddependents depadd ON depadd.source = ((nsp.nspname::text || '.'::text) || cls.relname::text)
LEFT JOIN cterequirements req ON req.rel = ((nsp.nspname::text || '.'::text) || cls.relname::text)
LEFT JOIN cteaddrequirements addreq ON addreq.rel = ((nsp.nspname::text || '.'::text) || cls.relname::text)
WHERE (cls.relkind = ANY (ARRAY['r'::"char", 'v'::"char", 'm'::"char", 'f'::"char"])) AND nsp.nspname !~~ 'pg_toast%'::text AND (nsp.nspname <> ALL (ARRAY['information_schema'::name, 'pg_catalog'::name]))
ORDER BY nsp.nspname, cls.relname;
COMMENT ON VIEW public.c77_dep_dependencies_map_with_foreign IS 'Maps dependencies between database objects including foreign tables';
-- Circular Dependency Detector
CREATE OR REPLACE FUNCTION public.c77_dep_detect_circular_dependencies(
)
RETURNS TABLE(object1 text, object2 text, dependency_type text)
LANGUAGE 'plpgsql'
COST 100
VOLATILE PARALLEL UNSAFE
ROWS 1000
AS $BODY$
BEGIN
RETURN QUERY
-- Direct circular dependencies
SELECT
a.relation AS object1,
b.relation AS object2,
'Direct circular' AS dependency_type
FROM public.c77_dep_dependencies_map_with_foreign a
JOIN public.c77_dep_dependencies_map_with_foreign b ON
a.relation <> b.relation AND
a.requirements LIKE '%' || b.relation || '%' AND
b.requirements LIKE '%' || a.relation || '%'
UNION
-- Indirect circular dependencies
SELECT
a.relation AS object1,
b.relation AS object2,
'Indirect circular' AS dependency_type
FROM public.c77_dep_dependencies_map_with_foreign a
JOIN public.c77_dep_dependencies_map_with_foreign b ON
a.relation <> b.relation AND
a.add_requirements LIKE '%' || b.relation || '%' AND
b.add_requirements LIKE '%' || a.relation || '%'
WHERE NOT EXISTS (
SELECT 1
FROM public.c77_dep_dependencies_map_with_foreign c
JOIN public.c77_dep_dependencies_map_with_foreign d ON
c.relation = a.relation AND
d.relation = b.relation AND
c.requirements LIKE '%' || d.relation || '%' AND
d.requirements LIKE '%' || c.relation || '%'
);
END;
$BODY$;
COMMENT ON FUNCTION public.c77_dep_detect_circular_dependencies() IS 'Detects circular dependencies between database objects';
-- Orphaned Objects Tracker
CREATE OR REPLACE VIEW public.c77_dep_orphaned_objects
AS
SELECT relation,
object_type,
owner
FROM c77_dep_dependencies_map_with_foreign
WHERE deps = 0 AND reqs = 0;
COMMENT ON VIEW public.c77_dep_orphaned_objects IS 'Identifies database objects with no dependencies or requirements';
-- Schema Complexity Assessment
CREATE OR REPLACE VIEW public.c77_dep_schema_complexity
AS
SELECT split_part(relation, '.'::text, 1) AS schema_name,
count(*) AS total_objects,
sum(deps) AS total_dependencies,
round(avg(deps), 2) AS avg_dependencies_per_object,
max(deps) AS max_dependencies,
count(*) FILTER (WHERE deps > 10) AS highly_dependent_objects
FROM c77_dep_dependencies_map_with_foreign
GROUP BY (split_part(relation, '.'::text, 1))
ORDER BY (sum(deps)) DESC;
COMMENT ON VIEW public.c77_dep_schema_complexity IS 'Provides metrics on schema complexity and dependencies';
-- Database Object Type Summary
CREATE OR REPLACE VIEW public.c77_dep_object_type_summary
AS
SELECT object_type,
count(*) AS object_count,
round(100.0 * count(*)::numeric / sum(count(*)) OVER (), 2) AS percentage,
sum(deps) AS total_dependencies,
round(avg(deps), 2) AS avg_dependencies_per_object,
max(deps) AS max_dependencies
FROM c77_dep_dependencies_map_with_foreign
GROUP BY object_type
ORDER BY (count(*)) DESC;
COMMENT ON VIEW public.c77_dep_object_type_summary IS 'Provides a summary of object types and their dependency characteristics';
-- Dependency Risk Assessment
CREATE OR REPLACE VIEW public.c77_dep_risk_assessment
AS
SELECT relation,
object_type,
deps,
add_deps,
deps * 2 + add_deps +
CASE
WHEN object_type = 'VIEW'::text THEN 3
WHEN object_type = 'MATV'::text THEN 4
WHEN object_type = 'FOREIGN TABLE'::text THEN 5
ELSE 1
END AS risk_score,
CASE
WHEN (deps + add_deps) > 20 THEN 'HIGH'::text
WHEN (deps + add_deps) > 10 THEN 'MEDIUM'::text
ELSE 'LOW'::text
END AS risk_level
FROM c77_dep_dependencies_map_with_foreign;
COMMENT ON VIEW public.c77_dep_risk_assessment IS 'Assesses risk level of modifying database objects based on dependencies';
-- Dependency Hub Objects
CREATE OR REPLACE VIEW public.c77_dep_hub_objects
AS
SELECT relation,
object_type,
deps + add_deps AS total_dependencies,
deps AS direct_dependencies,
add_deps AS indirect_dependencies,
reqs + add_reqs AS total_requirements,
reqs AS direct_requirements,
add_reqs AS indirect_requirements
FROM c77_dep_dependencies_map_with_foreign
WHERE (deps + add_deps) > 5
ORDER BY (deps + add_deps) DESC
LIMIT 20;
COMMENT ON VIEW public.c77_dep_hub_objects IS 'Identifies central hub objects with many dependencies';
-- Cleanup Candidates
CREATE OR REPLACE VIEW public.c77_dep_cleanup_candidates
AS
SELECT c77_dep_dependencies_map_with_foreign.relation,
c77_dep_dependencies_map_with_foreign.object_type,
'No dependencies, potentially unused'::text AS reason
FROM c77_dep_dependencies_map_with_foreign
WHERE c77_dep_dependencies_map_with_foreign.deps = 0
UNION ALL
SELECT DISTINCT a.relation,
a.object_type,
'Circular dependency with '::text || b.relation AS reason
FROM c77_dep_dependencies_map_with_foreign a
JOIN c77_dep_dependencies_map_with_foreign b ON a.relation <> b.relation AND (a.requirements ~~ (('%'::text || b.relation) || '%'::text) OR a.add_requirements ~~ (('%'::text || b.relation) || '%'::text)) AND (b.requirements ~~ (('%'::text || a.relation) || '%'::text) OR b.add_requirements ~~ (('%'::text || a.relation) || '%'::text));
COMMENT ON VIEW public.c77_dep_cleanup_candidates IS 'Identifies objects that may be candidates for cleanup or refactoring';
-- Impact Analysis Function
CREATE OR REPLACE FUNCTION public.c77_dep_analyze_drop_impact(
p_object_name text)
RETURNS TABLE(affected_object text, obj_type text, impact_level integer, dependency_path text)
LANGUAGE 'plpgsql'
COST 100
VOLATILE PARALLEL UNSAFE
ROWS 1000
AS $BODY$
DECLARE
affected_objects text[] := '{}';
current_level int := 0;
current_batch text[] := ARRAY[p_object_name];
next_batch text[] := '{}';
v_rel text;
v_type text;
dep text;
BEGIN
-- First, check if the object exists
IF NOT EXISTS (
SELECT 1 FROM public.c77_dep_dependencies_map_with_foreign
WHERE relation = p_object_name
) THEN
RAISE EXCEPTION 'Object % not found in dependency map', p_object_name;
END IF;
-- Return the object itself at level 0
SELECT relation, object_type
INTO v_rel, v_type
FROM public.c77_dep_dependencies_map_with_foreign
WHERE relation = p_object_name;
affected_object := v_rel;
obj_type := v_type;
impact_level := 0;
dependency_path := v_rel;
RETURN NEXT;
-- Add to affected objects
affected_objects := array_append(affected_objects, p_object_name);
-- Process levels until no new objects are found
WHILE array_length(current_batch, 1) > 0 LOOP
current_level := current_level + 1;
next_batch := '{}';
-- For each object in current batch
FOREACH dep IN ARRAY current_batch LOOP
-- Find objects that depend on this one
FOR v_rel, v_type IN
SELECT
dm.relation,
dm.object_type
FROM public.c77_dep_dependencies_map_with_foreign dm
WHERE
(dm.requirements LIKE '%' || dep || '%' OR
dm.add_requirements LIKE '%' || dep || '%')
AND NOT dm.relation = ANY(affected_objects)
LOOP
-- Add to results
affected_object := v_rel;
obj_type := v_type;
impact_level := current_level;
dependency_path := p_object_name || ' -> ' || v_rel;
RETURN NEXT;
-- Add to affected objects and next batch
affected_objects := array_append(affected_objects, v_rel);
next_batch := array_append(next_batch, v_rel);
END LOOP;
END LOOP;
current_batch := next_batch;
END LOOP;
RETURN;
END;
$BODY$;
COMMENT ON FUNCTION public.c77_dep_analyze_drop_impact(text) IS 'Analyzes impact of dropping a database object by showing affected dependencies';
-- Export dependency graph in DOT format
CREATE OR REPLACE FUNCTION public.c77_dep_export_dependency_graph(
schema_filter text DEFAULT NULL::text,
max_depth integer DEFAULT 3,
include_foreign boolean DEFAULT true)
RETURNS text
LANGUAGE 'plpgsql'
COST 100
VOLATILE PARALLEL UNSAFE
AS $BODY$
DECLARE
result text := 'digraph dependencies {' || E'\n';
result_nodes text := '';
result_edges text := '';
v_rel record;
req_array text[];
req text;
BEGIN
-- Create nodes with styling based on object type
FOR v_rel IN
SELECT
relation,
object_type
FROM public.c77_dep_dependencies_map_with_foreign
WHERE (schema_filter IS NULL OR split_part(relation, '.', 1) = schema_filter)
AND (include_foreign OR object_type <> 'FOREIGN TABLE')
LOOP
-- Add node styling based on object type
result_nodes := result_nodes || ' "' || v_rel.relation || '" [';
CASE v_rel.object_type
WHEN 'TABLE' THEN
result_nodes := result_nodes || 'shape=box, style=filled, fillcolor=lightblue';
WHEN 'VIEW' THEN
result_nodes := result_nodes || 'shape=ellipse, style=filled, fillcolor=lightgreen';
WHEN 'MATV' THEN
result_nodes := result_nodes || 'shape=ellipse, style=filled, fillcolor=lightcyan';
WHEN 'FOREIGN TABLE' THEN
result_nodes := result_nodes || 'shape=box, style=filled, fillcolor=lightyellow';
ELSE
result_nodes := result_nodes || 'shape=diamond';
END CASE;
result_nodes := result_nodes || '];' || E'\n';
END LOOP;
-- Create edges for dependencies
FOR v_rel IN
SELECT
relation,
requirements
FROM public.c77_dep_dependencies_map_with_foreign
WHERE (schema_filter IS NULL OR split_part(relation, '.', 1) = schema_filter)
AND (include_foreign OR object_type <> 'FOREIGN TABLE')
AND requirements IS NOT NULL
AND requirements <> ''
LOOP
-- Split requirements into array
req_array := string_to_array(v_rel.requirements, ' | ');
-- Create edge for each requirement
IF req_array IS NOT NULL THEN
FOREACH req IN ARRAY req_array LOOP
IF req <> '' THEN
-- Only include edges where both nodes match filter criteria
IF schema_filter IS NULL OR split_part(req, '.', 1) = schema_filter THEN
result_edges := result_edges || ' "' || v_rel.relation || '" -> "' || req || '";' || E'\n';
END IF;
END IF;
END LOOP;
END IF;
END LOOP;
-- Combine nodes and edges
result := result || result_nodes || result_edges || '}';
RETURN result;
END;
$BODY$;
COMMENT ON FUNCTION public.c77_dep_export_dependency_graph(text, int, boolean) IS 'Exports dependency graph in DOT format for visualization with Graphviz';
-- Schema change simulation
CREATE OR REPLACE FUNCTION public.c77_dep_simulate_schema_change(
p_schema_name text,
p_new_schema_name text DEFAULT NULL::text)
RETURNS TABLE(object_name text, obj_type text, affected_dependencies integer, affected_objects text[])
LANGUAGE 'plpgsql'
COST 100
VOLATILE PARALLEL UNSAFE
ROWS 1000
AS $BODY$
BEGIN
RETURN QUERY
SELECT
relation AS object_name,
dm.object_type AS obj_type,
deps::int AS affected_dependencies,
array_agg(dep_obj) AS affected_objects
FROM
public.c77_dep_dependencies_map_with_foreign dm
CROSS JOIN LATERAL unnest(
CASE WHEN dm.dependents <> ''
THEN string_to_array(dm.dependents, ' | ')
ELSE '{}'::text[]
END
) AS dep_obj
WHERE
split_part(relation, '.', 1) = p_schema_name
GROUP BY
relation, dm.object_type, deps
ORDER BY
deps DESC;
END;
$BODY$;
COMMENT ON FUNCTION public.c77_dep_simulate_schema_change(text, text) IS 'Simulates the impact of changing a schema name';
-- Migration Order Function
CREATE OR REPLACE FUNCTION public.c77_dep_generate_migration_order(
)
RETURNS TABLE(migration_phase integer, objects_to_migrate text[], object_count integer)
LANGUAGE 'plpgsql'
COST 100
VOLATILE PARALLEL UNSAFE
ROWS 1000
AS $BODY$
DECLARE
remaining_objects text[];
current_level integer := 0;
objects_at_level text[];
current_object text;
current_req text;
req_array text[];
all_requirements_met boolean;
placed_objects text[] := '{}';
progress_made boolean;
BEGIN
-- Get all objects
SELECT array_agg(relation)
INTO remaining_objects
FROM public.c77_dep_dependencies_map_with_foreign;
-- Keep processing until all objects are placed or no progress is made
WHILE array_length(remaining_objects, 1) > 0 LOOP
objects_at_level := '{}';
progress_made := false;
-- Find objects for current level
FOR i IN 1..array_length(remaining_objects, 1) LOOP
current_object := remaining_objects[i];
-- Get requirements for this object
SELECT string_to_array(COALESCE(requirements, ''), ' | ')
INTO req_array
FROM public.c77_dep_dependencies_map_with_foreign
WHERE relation = current_object;
-- Check if all requirements are already placed or empty
all_requirements_met := true;
-- Empty requirements can go in first level
IF req_array IS NULL OR array_length(req_array, 1) IS NULL OR req_array = '{}' THEN
all_requirements_met := true;
ELSE
-- Check each requirement
FOREACH current_req IN ARRAY req_array LOOP
IF current_req <> '' AND NOT current_req = ANY(placed_objects) THEN
all_requirements_met := false;
EXIT;
END IF;
END LOOP;
END IF;
-- If all requirements met, add to current level
IF all_requirements_met THEN
objects_at_level := array_append(objects_at_level, current_object);
placed_objects := array_append(placed_objects, current_object);
progress_made := true;
END IF;
END LOOP;
-- If we placed objects in this level, return the results
IF array_length(objects_at_level, 1) > 0 THEN
migration_phase := current_level;
objects_to_migrate := objects_at_level;
object_count := array_length(objects_at_level, 1);
RETURN NEXT;
-- Remove placed objects from remaining set
SELECT array_agg(o)
INTO remaining_objects
FROM unnest(remaining_objects) AS o
WHERE NOT o = ANY(objects_at_level);
END IF;
-- Break if no progress was made (might be due to circular dependencies)
IF NOT progress_made THEN
-- Add remaining objects to a final level (these likely have circular dependencies)
IF array_length(remaining_objects, 1) > 0 THEN
migration_phase := current_level + 1;
objects_to_migrate := remaining_objects;
object_count := array_length(remaining_objects, 1);
RETURN NEXT;
remaining_objects := '{}';
END IF;
END IF;
current_level := current_level + 1;
END LOOP;
RETURN;
END;
$BODY$;
COMMENT ON FUNCTION public.c77_dep_generate_migration_order() IS 'Generates a migration order for objects based on their dependencies';
-- Function to generate a database dependency report
CREATE OR REPLACE FUNCTION public.c77_dep_generate_report(
p_schema_name text DEFAULT NULL::text,
p_include_orphans boolean DEFAULT true,
p_include_circular boolean DEFAULT true)
RETURNS text
LANGUAGE 'plpgsql'
COST 100
VOLATILE PARALLEL UNSAFE
AS $BODY$
DECLARE
v_report text := '';
v_schema_count integer;
v_object_count integer;
v_dependency_count integer;
v_orphan_count integer;
v_circular_count integer;
v_hub_objects record;
v_circular_deps record;
BEGIN
-- Report header
v_report := v_report || '=========================================' || E'\n';
v_report := v_report || 'DATABASE DEPENDENCY ANALYSIS REPORT' || E'\n';
v_report := v_report || '=========================================' || E'\n\n';
v_report := v_report || 'Generated on: ' || now() || E'\n\n';
-- Filter criteria
IF p_schema_name IS NOT NULL THEN
v_report := v_report || 'Schema filter: ' || p_schema_name || E'\n\n';
END IF;
-- Summary statistics
SELECT
count(DISTINCT split_part(relation, '.', 1)),
count(*),
sum(deps)
INTO
v_schema_count,
v_object_count,
v_dependency_count
FROM public.c77_dep_dependencies_map_with_foreign
WHERE p_schema_name IS NULL OR split_part(relation, '.', 1) = p_schema_name;
v_report := v_report || 'SUMMARY STATISTICS:' || E'\n';
v_report := v_report || '-------------------' || E'\n';
v_report := v_report || 'Total schemas: ' || v_schema_count || E'\n';
v_report := v_report || 'Total objects: ' || v_object_count || E'\n';
v_report := v_report || 'Total dependencies: ' || v_dependency_count || E'\n\n';
-- Object type distribution
v_report := v_report || 'OBJECT TYPE DISTRIBUTION:' || E'\n';
v_report := v_report || '------------------------' || E'\n';
FOR v_hub_objects IN
SELECT
object_type,
count(*) AS cnt,
round(100.0 * count(*) / v_object_count, 1) AS pct
FROM public.c77_dep_dependencies_map_with_foreign
WHERE p_schema_name IS NULL OR split_part(relation, '.', 1) = p_schema_name
GROUP BY object_type
ORDER BY count(*) DESC
LOOP
v_report := v_report || v_hub_objects.object_type || ': ' ||
v_hub_objects.cnt || ' (' ||
v_hub_objects.pct || '%)' || E'\n';
END LOOP;
v_report := v_report || E'\n';
-- Top hub objects
v_report := v_report || 'TOP DEPENDENCY HUBS:' || E'\n';
v_report := v_report || '-------------------' || E'\n';
FOR v_hub_objects IN
SELECT
relation,
object_type,
deps AS direct_deps,
add_deps AS indirect_deps
FROM public.c77_dep_dependencies_map_with_foreign
WHERE (p_schema_name IS NULL OR split_part(relation, '.', 1) = p_schema_name)
ORDER BY deps + add_deps DESC
LIMIT 10
LOOP
v_report := v_report || v_hub_objects.relation || ' (' || v_hub_objects.object_type ||
'): Direct deps: ' || v_hub_objects.direct_deps ||
', Indirect: ' || v_hub_objects.indirect_deps || E'\n';
END LOOP;
v_report := v_report || E'\n';
-- Orphaned objects
IF p_include_orphans THEN
SELECT count(*) INTO v_orphan_count
FROM public.c77_dep_dependencies_map_with_foreign
WHERE deps = 0
AND (p_schema_name IS NULL OR split_part(relation, '.', 1) = p_schema_name);
v_report := v_report || 'ORPHANED OBJECTS (' || v_orphan_count || '):' || E'\n';
v_report := v_report || '-------------------' || E'\n';
IF v_orphan_count > 0 THEN
FOR v_hub_objects IN
SELECT relation, object_type
FROM public.c77_dep_dependencies_map_with_foreign
WHERE deps = 0
AND (p_schema_name IS NULL OR split_part(relation, '.', 1) = p_schema_name)
ORDER BY relation
LIMIT 20
LOOP
v_report := v_report || v_hub_objects.relation || ' (' || v_hub_objects.object_type || ')' || E'\n';
END LOOP;
IF v_orphan_count > 20 THEN
v_report := v_report || '... and ' || (v_orphan_count - 20) || ' more' || E'\n';
END IF;
ELSE
v_report := v_report || 'No orphaned objects found.' || E'\n';
END IF;
v_report := v_report || E'\n';
END IF;
-- Circular dependencies section - using the dedicated function
IF p_include_circular THEN
-- Count circular dependencies
SELECT count(*) INTO v_circular_count
FROM public.c77_dep_detect_circular_dependencies() cd
WHERE p_schema_name IS NULL OR split_part(cd.object1, '.', 1) = p_schema_name;
v_report := v_report || 'CIRCULAR DEPENDENCIES (' || v_circular_count || '):' || E'\n';
v_report := v_report || '-------------------------' || E'\n';
IF v_circular_count > 0 THEN
-- List circular dependencies
FOR v_circular_deps IN
SELECT object1, object2, dependency_type
FROM public.c77_dep_detect_circular_dependencies()
WHERE p_schema_name IS NULL OR split_part(object1, '.', 1) = p_schema_name
ORDER BY dependency_type, object1, object2
LIMIT 20
LOOP
v_report := v_report || v_circular_deps.object1 || ' <-> ' ||
v_circular_deps.object2 || ' (' ||
v_circular_deps.dependency_type || ')' || E'\n';
END LOOP;
IF v_circular_count > 20 THEN
v_report := v_report || '... and ' || (v_circular_count - 20) || ' more' || E'\n';
END IF;
ELSE
v_report := v_report || 'No circular dependencies found.' || E'\n';
END IF;
v_report := v_report || E'\n';
END IF;
-- Recommendations
v_report := v_report || 'RECOMMENDATIONS:' || E'\n';
v_report := v_report || '----------------' || E'\n';
-- Recommendation for schema refactoring if there are many objects in one schema
IF EXISTS (
SELECT 1
FROM (
SELECT
split_part(relation, '.', 1) AS schema_name,
count(*) AS object_count
FROM public.c77_dep_dependencies_map_with_foreign
WHERE p_schema_name IS NULL OR split_part(relation, '.', 1) = p_schema_name
GROUP BY split_part(relation, '.', 1)
) AS schema_counts
WHERE object_count > 100
) THEN
v_report := v_report || '- Consider schema refactoring for large schemas (>100 objects)' || E'\n';
END IF;
-- Recommendation for circular dependencies
IF v_circular_count > 0 THEN
v_report := v_report || '- Resolve circular dependencies to improve database maintainability' || E'\n';
END IF;
-- Recommendation for orphaned objects
IF v_orphan_count > 0 THEN
v_report := v_report || '- Review orphaned objects for potential removal or cleanup' || E'\n';
END IF;
-- Recommendation for dependency hubs
IF EXISTS (
SELECT 1
FROM public.c77_dep_dependencies_map_with_foreign
WHERE deps > 15 AND (p_schema_name IS NULL OR split_part(relation, '.', 1) = p_schema_name)
) THEN
v_report := v_report || '- Consider refactoring objects with many dependencies (>15)' || E'\n';
END IF;
RETURN v_report;
END;
$BODY$;
COMMENT ON FUNCTION public.c77_dep_generate_report(text, boolean, boolean) IS 'Generates a comprehensive dependency analysis report for the database';
-- Extension setup completion
DO $$
BEGIN
RAISE NOTICE 'c77_dep extension version 1.0.0 has been successfully installed.';
RAISE NOTICE 'Use the following views and functions to analyze database dependencies:';
RAISE NOTICE '- c77_dep_dependencies_map - Base dependency map';
RAISE NOTICE '- c77_dep_dependencies_map_with_foreign - Enhanced dependency map with foreign tables';
RAISE NOTICE '- c77_dep_orphaned_objects - Objects with no dependencies';
RAISE NOTICE '- c77_dep_schema_complexity - Schema complexity metrics';
RAISE NOTICE '- c77_dep_object_type_summary - Summary of object types';
RAISE NOTICE '- c77_dep_risk_assessment - Risk assessment for schema changes';
RAISE NOTICE '- c77_dep_hub_objects - Objects with many dependencies';
RAISE NOTICE '- c77_dep_cleanup_candidates - Objects that might need cleanup';
RAISE NOTICE '- c77_dep_analyze_drop_impact() - Analyze impact of dropping an object';
RAISE NOTICE '- c77_dep_detect_circular_dependencies() - Detect circular dependencies';
RAISE NOTICE '- c77_dep_export_dependency_graph() - Export dependencies in DOT format';
RAISE NOTICE '- c77_dep_simulate_schema_change() - Simulate schema rename impact';
RAISE NOTICE '- c77_dep_generate_migration_order() - Generate suggested migration order';
RAISE NOTICE '- c77_dep_generate_report() - Generate dependency analysis report';
END
$$;