From f4f80e220bf3e4abd223a66f476422855b2847c9 Mon Sep 17 00:00:00 2001 From: Rodolphe Quiedeville Date: Wed, 11 Dec 2024 15:27:09 +0100 Subject: [PATCH] Add Missing files --- dist/schedoc.sql | 36 +++++++++++---- sql/table.sql | 97 +++++++---------------------------------- test/sql/table_test.sql | 6 +-- 3 files changed, 44 insertions(+), 95 deletions(-) diff --git a/dist/schedoc.sql b/dist/schedoc.sql index 92d90bc..475a050 100644 --- a/dist/schedoc.sql +++ b/dist/schedoc.sql @@ -4,10 +4,26 @@ CREATE TYPE schedoc_status AS ENUM ('public', 'private', 'legacy', 'wip'); +-- The table schedoc_status stores only one value, this table is used +-- as a foreign key target +-- +-- +CREATE TABLE schedoc_valid (status boolean NOT NULL PRIMARY KEY CHECK (status = true)); +INSERT INTO schedoc_valid (status) VALUES (true); +-- +-- The column is_valid references schedoc_status to make sure we have +-- true in this column but in a way that permits to deferre the check +-- of the constraint. +-- +-- When adding a new column there is no COMMENT on it, but this way we +-- enforce that any new column creation must include in the same +-- transaction a COMMENT statement. +-- CREATE TABLE schedoc_column_raw ( objoid oid, objsubid oid, comment jsonb, + is_valid boolean DEFAULT false REFERENCES schedoc_valid (status) DEFERRABLE INITIALLY DEFERRED, status schedoc_status, PRIMARY KEY (objoid, objsubid) ); @@ -19,6 +35,8 @@ CREATE VIEW schedoc_column_comments AS JOIN pg_class c ON c.oid = ccr.objoid JOIN pg_attribute a ON (a.attnum = ccr.objsubid AND a.attrelid = ccr.objoid); +-- +-- -- -- -- @@ -43,7 +61,7 @@ BEGIN 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 + %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, @@ -67,7 +85,9 @@ $$', schemaname, schemaname, schemaname, schemaname, schemaname, schemaname); END; $EOF$; - +-- +-- +-- CREATE OR REPLACE FUNCTION schedoc_get_column_description(bjoid oid, bjsubid oid) RETURNS text LANGUAGE plpgsql AS @@ -81,7 +101,9 @@ BEGIN RETURN description; END; $EOF$; - +-- +-- +-- CREATE OR REPLACE FUNCTION schedoc_get_column_status(bjoid oid, bjsubid oid) RETURNS text LANGUAGE plpgsql AS @@ -95,10 +117,6 @@ BEGIN RETURN status; END; $EOF$; - --- CREATE TRIGGER schedoc_trg --- BEFORE INSERT ON ddl_history --- FOR EACH ROW --- EXECUTE PROCEDURE schedoc_trg(); - +-- +-- SELECT schedoc_start(); diff --git a/sql/table.sql b/sql/table.sql index 92d90bc..033c2fa 100644 --- a/sql/table.sql +++ b/sql/table.sql @@ -4,10 +4,26 @@ CREATE TYPE schedoc_status AS ENUM ('public', 'private', 'legacy', 'wip'); +-- The table schedoc_status stores only one value, this table is used +-- as a foreign key target +-- +-- +CREATE TABLE schedoc_valid (status boolean NOT NULL PRIMARY KEY CHECK (status = true)); +INSERT INTO schedoc_valid (status) VALUES (true); +-- +-- The column is_valid references schedoc_status to make sure we have +-- true in this column but in a way that permits to deferre the check +-- of the constraint. +-- +-- When adding a new column there is no COMMENT on it, but this way we +-- enforce that any new column creation must include in the same +-- transaction a COMMENT statement. +-- CREATE TABLE schedoc_column_raw ( objoid oid, objsubid oid, comment jsonb, + is_valid boolean DEFAULT false REFERENCES schedoc_valid (status) DEFERRABLE INITIALLY DEFERRED, status schedoc_status, PRIMARY KEY (objoid, objsubid) ); @@ -21,84 +37,3 @@ CREATE VIEW schedoc_column_comments AS -- -- --- -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(); diff --git a/test/sql/table_test.sql b/test/sql/table_test.sql index 79d39a3..957ed82 100644 --- a/test/sql/table_test.sql +++ b/test/sql/table_test.sql @@ -6,7 +6,7 @@ SET search_path=public,pgtap; BEGIN; -SELECT plan(8); +SELECT plan(5); SELECT has_extension('schedoc'); SELECT has_table('schedoc_column_raw'); @@ -16,8 +16,4 @@ SELECT has_enum('schedoc_status'); SELECT enum_has_labels('schedoc_status', ARRAY['public', 'private', 'legacy', 'wip']); -SELECT has_function('schedoc_start'); -SELECT has_function('schedoc_get_column_description', ARRAY['oid', 'oid']); -SELECT has_function('schedoc_get_column_status', ARRAY['oid', 'oid']); - ROLLBACK;