-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #6 from ZeroGachis/develop
MEP
- Loading branch information
Showing
9 changed files
with
319 additions
and
27 deletions.
There are no files selected for viewing
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
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,2 +1,50 @@ | ||
# data-contract | ||
Cross documentation between Django and DBT projects | ||
# schedoc | ||
|
||
schedoc means schema documentation, it's a tool to build an automatic | ||
documentation based on COMMENT on PostgresSQL objects. schedoc require | ||
the extension | ||
[(ddl_historization](https://pgxn.org/dist/ddl_historization/) to work | ||
|
||
COMMENT are set on columns in a json format with predefined values like status. | ||
|
||
``` | ||
COMMENT ON COLUMN foobar.id IS '{"status": "private"}' | ||
``` | ||
|
||
Comment are parsed and store in a table to make information easy accessible | ||
|
||
``` | ||
[local]:5437 rodo@jeanneau=# SELECT * FROM schedoc_column_comments ; | ||
databasename | tablename | columnname | status | ||
--------------+-----------+------------+--------- | ||
jeanneau | foobar | id | private | ||
(1 row) | ||
``` | ||
|
||
## Install | ||
|
||
There is no other action to do, only CREATE EXTENSION, with CASCADE | ||
the dependency will be automatically created. | ||
|
||
``` | ||
CREATE EXTENSION schedoc CASCADE; | ||
``` | ||
|
||
## Why schedoc | ||
|
||
The final goal of the extension is to make information on column | ||
available to be crossed with information from other systems. | ||
|
||
Here at Smartway we add comments on every field in Django Models with | ||
[db_comment](https://docs.djangoproject.com/en/5.1/ref/models/fields/#db-comment) | ||
and cross this information with the DBT doc generated. As is | ||
developpers can define the usability of every columns for data | ||
analysts and follow what we call a Data Contract. | ||
|
||
This extension is at early stage for now, we will extend the JSON | ||
format in the following month. | ||
|
||
## Free Software | ||
|
||
We released this extension as a free software as it may be useful for | ||
any other company with the same need. |
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
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,104 @@ | ||
-- | ||
-- | ||
-- | ||
|
||
CREATE TYPE schedoc_status AS ENUM ('public', 'private', 'legacy', 'wip'); | ||
|
||
CREATE TABLE schedoc_column_raw ( | ||
objoid oid, | ||
objsubid oid, | ||
comment jsonb, | ||
status schedoc_status, | ||
PRIMARY KEY (objoid, objsubid) | ||
); | ||
|
||
CREATE VIEW schedoc_column_comments AS | ||
|
||
SELECT current_database() as databasename, c.relname as tablename, a.attname as columnname, status | ||
FROM schedoc_column_raw ccr | ||
JOIN pg_class c ON c.oid = ccr.objoid | ||
JOIN pg_attribute a ON (a.attnum = ccr.objsubid AND a.attrelid = ccr.objoid); | ||
|
||
-- | ||
-- | ||
-- | ||
CREATE OR REPLACE FUNCTION schedoc_start() | ||
RETURNS void | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
schemaname TEXT; | ||
BEGIN | ||
SELECT n.nspname FROM pg_extension e JOIN pg_namespace n ON n.oid=e.extnamespace WHERE e.extname='ddl_historization' INTO schemaname; | ||
|
||
-- | ||
-- Function to manage INSERT statements | ||
-- | ||
|
||
EXECUTE format('CREATE OR REPLACE FUNCTION %s.schedoc_trg() | ||
RETURNS trigger LANGUAGE plpgsql AS $$ | ||
BEGIN | ||
INSERT INTO %s.schedoc_column_raw (objoid, objsubid, comment, status) | ||
VALUES ( | ||
NEW.objoid, | ||
NEW.objsubid, | ||
%s.schedoc_get_column_description(NEW.objoid, NEW.objsubid)::jsonb, | ||
%s.schedoc_get_column_status(NEW.objoid, NEW.objsubid)::public.schedoc_status | ||
) ON CONFLICT (objoid, objsubid) | ||
DO UPDATE SET | ||
comment = %s.schedoc_get_column_description(EXCLUDED.objoid, EXCLUDED.objsubid)::jsonb, | ||
status = %s.schedoc_get_column_status(EXCLUDED.objoid, EXCLUDED.objsubid)::public.schedoc_status; | ||
RETURN NEW; | ||
END; | ||
$$', schemaname, schemaname, schemaname, schemaname, schemaname, schemaname); | ||
|
||
-- | ||
-- Create two triggers, one for UPDATE and one for INSERT | ||
-- | ||
|
||
EXECUTE format(' | ||
CREATE TRIGGER schedoc_trg | ||
BEFORE INSERT ON %s.ddl_history | ||
FOR EACH ROW | ||
WHEN (NEW.ddl_tag = ''COMMENT'') | ||
EXECUTE PROCEDURE %s.schedoc_trg()', | ||
schemaname,schemaname); | ||
|
||
END; | ||
$EOF$; | ||
|
||
|
||
CREATE OR REPLACE FUNCTION schedoc_get_column_description(bjoid oid, bjsubid oid) | ||
RETURNS text | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
description TEXT; | ||
BEGIN | ||
SELECT pg_description.description FROM pg_description | ||
WHERE pg_description.objoid=bjoid AND pg_description.objsubid=bjsubid INTO description; | ||
|
||
RETURN description; | ||
END; | ||
$EOF$; | ||
|
||
CREATE OR REPLACE FUNCTION schedoc_get_column_status(bjoid oid, bjsubid oid) | ||
RETURNS text | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
status TEXT; | ||
BEGIN | ||
SELECT pg_description.description::jsonb->>'status' FROM pg_description | ||
WHERE pg_description.objoid=bjoid AND pg_description.objsubid=bjsubid INTO status; | ||
|
||
RETURN status; | ||
END; | ||
$EOF$; | ||
|
||
-- CREATE TRIGGER schedoc_trg | ||
-- BEFORE INSERT ON ddl_history | ||
-- FOR EACH ROW | ||
-- EXECUTE PROCEDURE schedoc_trg(); | ||
|
||
SELECT schedoc_start(); |
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,104 @@ | ||
-- | ||
-- | ||
-- | ||
|
||
CREATE TYPE schedoc_status AS ENUM ('public', 'private', 'legacy', 'wip'); | ||
|
||
CREATE TABLE schedoc_column_raw ( | ||
objoid oid, | ||
objsubid oid, | ||
comment jsonb, | ||
status schedoc_status, | ||
PRIMARY KEY (objoid, objsubid) | ||
); | ||
|
||
CREATE VIEW schedoc_column_comments AS | ||
|
||
SELECT current_database() as databasename, c.relname as tablename, a.attname as columnname, status | ||
FROM schedoc_column_raw ccr | ||
JOIN pg_class c ON c.oid = ccr.objoid | ||
JOIN pg_attribute a ON (a.attnum = ccr.objsubid AND a.attrelid = ccr.objoid); | ||
|
||
-- | ||
-- | ||
-- | ||
CREATE OR REPLACE FUNCTION schedoc_start() | ||
RETURNS void | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
schemaname TEXT; | ||
BEGIN | ||
SELECT n.nspname FROM pg_extension e JOIN pg_namespace n ON n.oid=e.extnamespace WHERE e.extname='ddl_historization' INTO schemaname; | ||
|
||
-- | ||
-- Function to manage INSERT statements | ||
-- | ||
|
||
EXECUTE format('CREATE OR REPLACE FUNCTION %s.schedoc_trg() | ||
RETURNS trigger LANGUAGE plpgsql AS $$ | ||
BEGIN | ||
INSERT INTO %s.schedoc_column_raw (objoid, objsubid, comment, status) | ||
VALUES ( | ||
NEW.objoid, | ||
NEW.objsubid, | ||
%s.schedoc_get_column_description(NEW.objoid, NEW.objsubid)::jsonb, | ||
%s.schedoc_get_column_status(NEW.objoid, NEW.objsubid)::public.schedoc_status | ||
) ON CONFLICT (objoid, objsubid) | ||
DO UPDATE SET | ||
comment = %s.schedoc_get_column_description(EXCLUDED.objoid, EXCLUDED.objsubid)::jsonb, | ||
status = %s.schedoc_get_column_status(EXCLUDED.objoid, EXCLUDED.objsubid)::public.schedoc_status; | ||
RETURN NEW; | ||
END; | ||
$$', schemaname, schemaname, schemaname, schemaname, schemaname, schemaname); | ||
|
||
-- | ||
-- Create two triggers, one for UPDATE and one for INSERT | ||
-- | ||
|
||
EXECUTE format(' | ||
CREATE TRIGGER schedoc_trg | ||
BEFORE INSERT ON %s.ddl_history | ||
FOR EACH ROW | ||
WHEN (NEW.ddl_tag = ''COMMENT'') | ||
EXECUTE PROCEDURE %s.schedoc_trg()', | ||
schemaname,schemaname); | ||
|
||
END; | ||
$EOF$; | ||
|
||
|
||
CREATE OR REPLACE FUNCTION schedoc_get_column_description(bjoid oid, bjsubid oid) | ||
RETURNS text | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
description TEXT; | ||
BEGIN | ||
SELECT pg_description.description FROM pg_description | ||
WHERE pg_description.objoid=bjoid AND pg_description.objsubid=bjsubid INTO description; | ||
|
||
RETURN description; | ||
END; | ||
$EOF$; | ||
|
||
CREATE OR REPLACE FUNCTION schedoc_get_column_status(bjoid oid, bjsubid oid) | ||
RETURNS text | ||
LANGUAGE plpgsql AS | ||
$EOF$ | ||
DECLARE | ||
status TEXT; | ||
BEGIN | ||
SELECT pg_description.description::jsonb->>'status' FROM pg_description | ||
WHERE pg_description.objoid=bjoid AND pg_description.objsubid=bjsubid INTO status; | ||
|
||
RETURN status; | ||
END; | ||
$EOF$; | ||
|
||
-- CREATE TRIGGER schedoc_trg | ||
-- BEFORE INSERT ON ddl_history | ||
-- FOR EACH ROW | ||
-- EXECUTE PROCEDURE schedoc_trg(); | ||
|
||
SELECT schedoc_start(); |
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
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,34 @@ | ||
-- | ||
-- We assume that ddl_historization is installed in public schema | ||
-- | ||
|
||
SET search_path=public,pgtap; | ||
|
||
BEGIN; | ||
|
||
SELECT plan(3); | ||
|
||
TRUNCATE ddl_history; | ||
|
||
-- 2 | ||
CREATE TABLE foobar_schedoc (id int); | ||
|
||
DROP EXTENSION IF EXISTS schedoc CASCADE; | ||
CREATE EXTENSION schedoc CASCADE; | ||
|
||
-- add test on schema to fail fast | ||
SELECT has_extension('schedoc'); | ||
SELECT has_table('schedoc_column_raw'); | ||
SELECT has_view('schedoc_column_comments'); | ||
|
||
COMMENT ON COLUMN foobar_schedoc.id IS '{"status": "private"}'; | ||
|
||
-- | ||
-- DROP manually the trigger and recreate it | ||
-- | ||
DROP TRIGGER schedoc_trg ON ddl_history ; | ||
SELECT schedoc_start(); | ||
|
||
COMMENT ON COLUMN foobar_schedoc.id IS '{"status": "private"}'; | ||
|
||
ROLLBACK; |
Oops, something went wrong.