Last active
November 21, 2024 14:59
-
-
Save Bilbottom/e1d3d677d2479e0602132327703ff15d to your computer and use it in GitHub Desktop.
Mermaid + DuckDB for generating entity-relationship diagrams
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
/* | |
Mermaid + DuckDB for generating entity-relationship diagrams | |
DuckDB version: 0.10.2 | |
Bill Wallis, 2024-05-09 | |
*/ | |
select version(); | |
create or replace table users ( | |
user_id integer not null primary key, | |
username varchar not null unique, | |
review_datetime timestamp, | |
unique (user_id, review_datetime) | |
); | |
create or replace table events ( | |
event_id integer not null primary key, | |
user_id integer not null references users(user_id), | |
event_datetime timestamp not null, | |
event_type varchar not null | |
); | |
create or replace table google_auth ( | |
user_id integer not null primary key references users(user_id), | |
last_accessed timestamp not null, | |
google_token varchar not null | |
); | |
create or replace table password_auth ( | |
user_id integer not null primary key references users(user_id), | |
last_accessed timestamp not null, | |
email varchar not null, | |
password varchar not null | |
); | |
create or replace table review_notes ( | |
user_id integer not null, | |
review_datetime timestamp not null, | |
notes varchar not null, | |
primary key (user_id, review_datetime), | |
foreign key (user_id, review_datetime) references users(user_id, review_datetime) | |
); | |
/* ER Generation */ | |
copy ( | |
select 'erDiagram' | |
union all | |
select format( | |
' {:s} {{{:s}}}', | |
table_name, string_agg(lower(data_type) || ' ' || column_name, ' ') | |
) | |
from information_schema.columns | |
group by table_name | |
union all | |
select format( | |
' {:s} }}o--o{{ {:s} : "{:s}"', | |
table_name, fk.table, fk.columns | |
) | |
from ( | |
select table_name, regexp_extract( | |
constraint_text, | |
'FOREIGN KEY \([A-Za-z_, ]+\) REFERENCES (\w+)\s?\(([A-Za-z_, ]+)\)', | |
['table', 'columns'] | |
) as fk | |
from duckdb_constraints() | |
where constraint_type = 'FOREIGN KEY' | |
) | |
) to 'er-diagram.mermaid' (header false, quote '', delimiter E'\n') | |
; |
Here's my take on this https://gist.github.com/michael-simons/bd89eaae2bc8ecdcc911c1b08268894b
Here's my take on this https://gist.github.com/michael-simons/bd89eaae2bc8ecdcc911c1b08268894b
Nice one, I defo prefer yours! Thanks for sharing 🤓
Thanks mate! But, it escalated quickly. There's now: https://gist.github.com/lmangani/dc9ea2ba0a0b2a54a1330e7db868e0bc
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
Lovely! Thank you.