Skip to content
Draft
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
24 changes: 24 additions & 0 deletions mermaid_diagrams/dependent_relations.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
--DROP VIEW gwolofs.dependent_relations;

CREATE OR REPLACE VIEW gwolofs.dependent_relations AS (
SELECT DISTINCT
rwr_cl.oid AS dep_oid,
ref_nsp.nspname AS ref_schema,
ref_cl.relname AS ref_name,
rwr_cl.relkind AS dep_type,
rwr_nsp.nspname AS dep_schema,
rwr_cl.relname AS dep_name,
ref_nsp.nspname || '.' || ref_cl.relname ||
--longer lines for inter-schema dependencies
CASE WHEN ref_nsp.nspname != rwr_nsp.nspname THEN ' ----> ' ELSE ' --> ' END
|| rwr_nsp.nspname || '.' || rwr_cl.relname AS mermaid_relation
FROM pg_depend AS dep
JOIN pg_class AS ref_cl ON dep.refobjid = ref_cl.oid
JOIN pg_namespace AS ref_nsp ON ref_cl.relnamespace = ref_nsp.oid
JOIN pg_rewrite AS rwr ON dep.objid = rwr.oid
JOIN pg_class AS rwr_cl ON rwr.ev_class = rwr_cl.oid
JOIN pg_namespace AS rwr_nsp ON rwr_cl.relnamespace = rwr_nsp.oid
WHERE
dep.deptype = 'n'
AND dep.classid = 'pg_rewrite'::regclass
);
53 changes: 53 additions & 0 deletions mermaid_diagrams/get_recursive_dependencies.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,53 @@
-- DROP FUNCTION gwolofs.get_recursive_dependencies(text, text);

CREATE OR REPLACE FUNCTION gwolofs.get_recursive_dependencies (
sch_name text,
obj_name text
) RETURNS TABLE(oid oid, obj_schema character varying, obj_name character varying, obj_type character varying)
LANGUAGE sql
COST 100
VOLATILE PARALLEL UNSAFE
ROWS 1000
AS $BODY$

SELECT oid, obj_schema, obj_name, obj_type
FROM (
WITH RECURSIVE recursive_deps(oid, obj_schema, obj_name, obj_type, depth) AS
(
SELECT
0::oid,
get_recursive_dependencies.sch_name::character varying COLLATE "C",
get_recursive_dependencies.obj_name::character varying COLLATE "C",
null::varchar,
0
UNION
SELECT
deps.dep_oid,
deps.dep_schema::varchar,
deps.dep_name::varchar,
deps.dep_type::varchar,
recursive_deps.depth + 1
FROM
(
SELECT dep_oid, ref_schema, ref_name, dep_type, dep_schema, dep_name
FROM gwolofs.dependent_relations
) AS deps
JOIN recursive_deps ON
deps.ref_schema = recursive_deps.obj_schema
AND deps.ref_name = recursive_deps.obj_name
WHERE
depth < 20
AND NOT (
deps.ref_schema = deps.dep_schema
AND deps.ref_name = deps.dep_name
)
)

SELECT oid, obj_schema, obj_name, obj_type, depth
FROM recursive_deps
WHERE depth >= 0
) AS t
GROUP BY t.oid, t.obj_schema, t.obj_name, t.obj_type
ORDER BY max(depth) DESC

$BODY$;
84 changes: 84 additions & 0 deletions mermaid_diagrams/mermaid_dependency_diagram.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,84 @@
--DROP FUNCTION gwolofs.mermaid_dependency_diagram(text, text);

CREATE OR REPLACE FUNCTION gwolofs.mermaid_dependency_diagram (
sch_name text,
obj_name text
) RETURNS TEXT
LANGUAGE sql
COST 100
VOLATILE PARALLEL UNSAFE
AS $BODY$

WITH dependencies AS (
--every object that has a relationship with some object in the recursive dependency tree (2nd level dependencies)
SELECT dep_schema, dep_name, ref_schema, ref_name
FROM gwolofs.dependent_relations AS deps
WHERE
dep_schema || '.' || dep_name IN (
SELECT obj_schema || '.' || obj_name FROM gwolofs.get_recursive_dependencies(
mermaid_dependency_diagram.sch_name,
mermaid_dependency_diagram.obj_name
)
)
OR ref_schema || '.' || ref_name IN (
SELECT obj_schema || '.' || obj_name FROM gwolofs.get_recursive_dependencies(
mermaid_dependency_diagram.sch_name,
mermaid_dependency_diagram.obj_name
)
)
)

--aggregate subgraphs and relationships into a complete diagram
SELECT
'%%{init: {''theme'': ''neutral'', ''flowchart'': {''defaultRenderer'': ''elk''}}}%%' || chr(10) ||
'flowchart TD' || chr(10) ||
string_agg(' ' || mermaid_object, chr(10)) AS mermaid_diagram
FROM (
--subgraphs for each schema
SELECT
'subgraph ' || obj_schema || chr(10) ||
--more work needed to give different shapes to different objects.
string_agg(' ' ||
--CASE obj_type
-- WHEN 'v' THEN lat.full_name || '{{' || lat.full_name || '}}'
-- WHEN 'm' THEN lat.full_name || '[[' || lat.full_name || ']]'
-- ELSE lat.full_name
--END,
objs.full_name || '[' || objs.obj_name || ']', chr(10)
) || chr(10) || ' end' AS mermaid_object
FROM (
SELECT DISTINCT
dep_schema AS obj_schema,
dep_schema || '.' || dep_name AS full_name,
dep_name AS obj_name
FROM dependencies
UNION
SELECT DISTINCT
ref_schema AS obj_schema,
ref_schema || '.' || ref_name AS full_name,
ref_name AS obj_name
FROM dependencies
) AS objs
GROUP BY obj_schema
UNION ALL
--relationships between nodes
SELECT mermaid_relation
FROM gwolofs.dependent_relations AS deps
WHERE dep_schema || '.' || dep_name IN (
SELECT obj_schema || '.' || obj_name
FROM gwolofs.get_recursive_dependencies(
mermaid_dependency_diagram.sch_name,
mermaid_dependency_diagram.obj_name
)
) AND NOT (
deps.ref_schema = deps.dep_schema
AND deps.ref_name = deps.dep_name
)
UNION ALL
SELECT ' style '
|| mermaid_dependency_diagram.sch_name || '.'
|| mermaid_dependency_diagram.obj_name
|| ' fill:#f9f,stroke:#333,stroke-width:4px,color:black'
) AS objects

$BODY$;
84 changes: 84 additions & 0 deletions mermaid_diagrams/mermaid_dependency_diagram_simple.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,84 @@
--DROP FUNCTION gwolofs.mermaid_dependency_diagram_simple(text, text);

CREATE OR REPLACE FUNCTION gwolofs.mermaid_dependency_diagram_simple (
sch_name text,
obj_name text
) RETURNS TEXT
LANGUAGE sql
COST 100
VOLATILE PARALLEL UNSAFE
AS $BODY$

WITH dependencies AS (
--every object that has a relationship with some object in the recursive dependency tree (2nd level dependencies)
SELECT dep_schema, dep_name, ref_schema, ref_name
FROM gwolofs.dependent_relations AS deps
WHERE
dep_schema || '.' || dep_name IN (
SELECT obj_schema || '.' || obj_name FROM gwolofs.get_recursive_dependencies(
mermaid_dependency_diagram_simple.sch_name,
mermaid_dependency_diagram_simple.obj_name
)
)
AND ref_schema || '.' || ref_name IN (
SELECT obj_schema || '.' || obj_name FROM gwolofs.get_recursive_dependencies(
mermaid_dependency_diagram_simple.sch_name,
mermaid_dependency_diagram_simple.obj_name
)
)
)

--aggregate subgraphs and relationships into a complete diagram
SELECT
'%%{init: {''theme'': ''neutral'', ''flowchart'': {''defaultRenderer'': ''elk''}}}%%' || chr(10) ||
'flowchart TD' || chr(10) ||
string_agg(' ' || mermaid_object, chr(10)) AS mermaid_diagram
FROM (
--subgraphs for each schema
SELECT
'subgraph ' || obj_schema || chr(10) ||
--more work needed to give different shapes to different objects.
string_agg(' ' ||
--CASE obj_type
-- WHEN 'v' THEN lat.full_name || '{{' || lat.full_name || '}}'
-- WHEN 'm' THEN lat.full_name || '[[' || lat.full_name || ']]'
-- ELSE lat.full_name
--END,
objs.full_name || '[[' || objs.full_name || ']]', chr(10)
) || chr(10) || ' end' AS mermaid_object
FROM (
SELECT DISTINCT dep_schema AS obj_schema, dep_schema || '.' || dep_name AS full_name
FROM dependencies
UNION
SELECT DISTINCT ref_schema AS obj_schema, ref_schema || '.' || ref_name AS full_name
FROM dependencies
) AS objs
GROUP BY obj_schema
UNION ALL
--relationships between nodes
SELECT mermaid_relation
FROM gwolofs.dependent_relations AS deps
WHERE ref_schema || '.' || ref_name IN (
SELECT obj_schema || '.' || obj_name
FROM gwolofs.get_recursive_dependencies(
mermaid_dependency_diagram_simple.sch_name,
mermaid_dependency_diagram_simple.obj_name
)
) AND dep_schema || '.' || dep_name IN (
SELECT obj_schema || '.' || obj_name
FROM gwolofs.get_recursive_dependencies(
mermaid_dependency_diagram_simple.sch_name,
mermaid_dependency_diagram_simple.obj_name
)
) AND NOT (
deps.ref_schema = deps.dep_schema
AND deps.ref_name = deps.dep_name
)
UNION ALL
SELECT ' style '
|| mermaid_dependency_diagram_simple.sch_name || '.'
|| mermaid_dependency_diagram_simple.obj_name
|| ' fill:#f9f,stroke:#333,stroke-width:4px'
) AS objects

$BODY$;