From 7e33eaa10f4299669ba246de2da8f9c034bcea86 Mon Sep 17 00:00:00 2001 From: Rodolphe Quiedeville Date: Fri, 15 Nov 2024 12:04:02 +0100 Subject: [PATCH] Add dist files and reduce number of pgversion to 16 and 17 --- .github/workflows/tests.yml | 2 +- dist/pgtle.schedoc-0.0.1.sql | 110 +++++++++++++++++++++++++++++++++++ 2 files changed, 111 insertions(+), 1 deletion(-) create mode 100644 dist/pgtle.schedoc-0.0.1.sql diff --git a/.github/workflows/tests.yml b/.github/workflows/tests.yml index 07930e2..b2ceb43 100644 --- a/.github/workflows/tests.yml +++ b/.github/workflows/tests.yml @@ -8,7 +8,7 @@ jobs: runs-on: ubuntu-latest strategy: matrix: - version: [ '12', '13', '14', '15', '16', '17' ] + version: [ '16', '17' ] container: pgxn/pgxn-tools env: diff --git a/dist/pgtle.schedoc-0.0.1.sql b/dist/pgtle.schedoc-0.0.1.sql new file mode 100644 index 0000000..faefec4 --- /dev/null +++ b/dist/pgtle.schedoc-0.0.1.sql @@ -0,0 +1,110 @@ +SELECT pgtle.install_extension +( + 'schedoc', + '0.0.1', + 'Schema documentation based on COMMENT', +$_pg_tle_$ +-- +-- +-- + +CREATE TYPE data_status AS ENUM ('public', 'private', 'legacy', 'wip'); + +CREATE TABLE schedoc_column_raw ( + objoid oid, + objsubid oid, + comment jsonb, + status data_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.get_column_description(NEW.objoid, NEW.objsubid)::jsonb, + %s.get_column_status(NEW.objoid, NEW.objsubid)::public.data_status + ) ON CONFLICT (objoid, objsubid) + DO UPDATE SET + comment = public.get_column_description(EXCLUDED.objoid, EXCLUDED.objsubid)::jsonb, + status = public.get_column_status(EXCLUDED.objoid, EXCLUDED.objsubid)::public.data_status; + RETURN NEW; + END; +$$', 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 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 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(); +$_pg_tle_$ +);