From 6cf60bd8b303e6366613123fce6bd1caf9d9500b Mon Sep 17 00:00:00 2001 From: Rodolphe Quiedeville Date: Thu, 12 Dec 2024 10:56:52 +0100 Subject: [PATCH] Do not auto start --- Makefile | 1 + README.md | 5 +- dist/pgtle.schedoc-0.0.2.sql | 161 ++++++++++++++++++++++++++------ dist/schedoc--0.0.2.sql | 161 ++++++++++++++++++++++++++------ dist/schedoc.sql | 161 ++++++++++++++++++++++++++------ sql/function-stop.sql | 22 +++++ sql/function.sql | 94 ++++++++++++++----- sql/start.sql | 16 +++- sql/table.sql | 29 +++++- test/create_column.sql | 4 + test/create_table.sql | 4 + test/integration_tests.sql | 49 ++++++++-- test/sql/function-stop_test.sql | 16 ++++ test/start_stop_tests.sql | 35 +++++++ 14 files changed, 630 insertions(+), 128 deletions(-) create mode 100644 sql/function-stop.sql create mode 100644 test/sql/function-stop_test.sql create mode 100644 test/start_stop_tests.sql diff --git a/Makefile b/Makefile index 8bd5b4f..e2f2bfd 100644 --- a/Makefile +++ b/Makefile @@ -29,6 +29,7 @@ clean: $(DIST): $(FILES) cat sql/table.sql > $@ cat sql/function.sql >> $@ + cat sql/function-stop.sql >> $@ cat sql/start.sql >> $@ cat $@ > dist/$(EXTENSION).sql diff --git a/README.md b/README.md index 8009916..722702d 100644 --- a/README.md +++ b/README.md @@ -23,11 +23,12 @@ Comment are parsed and store in a table to make information easy accessible ## Install -There is no other action to do, only CREATE EXTENSION, with CASCADE -the dependency will be automatically created. +Once the extension is installed, call the function `schedoc_start()` +to create the triggers and launch the process. ``` CREATE EXTENSION schedoc CASCADE; +SELECT schedoc_start(); ``` ## Why schedoc diff --git a/dist/pgtle.schedoc-0.0.2.sql b/dist/pgtle.schedoc-0.0.2.sql index 45dac06..bbb51c8 100644 --- a/dist/pgtle.schedoc-0.0.2.sql +++ b/dist/pgtle.schedoc-0.0.2.sql @@ -14,9 +14,14 @@ CREATE TYPE schedoc_status AS ENUM ('public', 'private', 'legacy', 'wip'); -- as a foreign key target -- -- -CREATE TABLE schedoc_valid (status boolean NOT NULL PRIMARY KEY CHECK (status = true)); +CREATE TABLE @extschema@.schedoc_valid (status boolean NOT NULL PRIMARY KEY CHECK (status = true)); INSERT INTO schedoc_valid (status) VALUES (true); -- +-- +-- +CREATE TABLE @extschema@.schedoc_valid_status (status schedoc_status NOT NULL PRIMARY KEY); +INSERT INTO schedoc_valid_status VALUES ('public'), ('private'), ('legacy'), ('wip'); +-- -- 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. @@ -25,16 +30,30 @@ INSERT INTO schedoc_valid (status) VALUES (true); -- enforce that any new column creation must include in the same -- transaction a COMMENT statement. -- -CREATE TABLE schedoc_column_raw ( +CREATE TABLE @extschema@.schedoc_column_raw ( objoid oid, objsubid oid, comment jsonb, - is_valid boolean DEFAULT false REFERENCES schedoc_valid (status) DEFERRABLE INITIALLY DEFERRED, - status schedoc_status, + is_valid boolean DEFAULT false REFERENCES @extschema@.schedoc_valid (status) DEFERRABLE INITIALLY DEFERRED, + status schedoc_status REFERENCES @extschema@.schedoc_valid_status (status) DEFERRABLE INITIALLY DEFERRED, PRIMARY KEY (objoid, objsubid) ); -CREATE VIEW schedoc_column_comments AS +-- +-- +-- +CREATE TABLE @extschema@.schedoc_column_log ( + objoid oid, + objsubid oid, + comment text, + is_valid boolean DEFAULT false, + created_at timestamp with time zone DEFAULT current_timestamp +); +-- +-- +-- + +CREATE VIEW @extschema@.schedoc_column_comments AS SELECT current_database() as databasename, c.relname as tablename, a.attname as columnname, status FROM schedoc_column_raw ccr @@ -46,47 +65,93 @@ CREATE VIEW schedoc_column_comments AS -- -- -- -CREATE OR REPLACE FUNCTION schedoc_start() +CREATE OR REPLACE FUNCTION @extschema@.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 $$ + CREATE OR REPLACE FUNCTION @extschema@.schedoc_trg() + RETURNS trigger LANGUAGE plpgsql AS $fsub$ BEGIN - INSERT INTO %s.schedoc_column_raw (objoid, objsubid, comment, status) + + -- keep a log of all values + INSERT INTO @extschema@.schedoc_column_log (objoid, objsubid, comment, is_valid) + VALUES ( + NEW.objoid, + NEW.objsubid, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid), + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON + ); + + + -- if the json is valid + IF schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON THEN + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, comment, status, is_valid) 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 + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid)::jsonb, + @extschema@.schedoc_get_column_status(NEW.objoid, NEW.objsubid)::public.schedoc_status, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON ) 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; + comment = @extschema@.schedoc_get_column_description(EXCLUDED.objoid, EXCLUDED.objsubid)::jsonb, + status = @extschema@.schedoc_get_column_status(EXCLUDED.objoid, EXCLUDED.objsubid)::public.schedoc_status, + is_valid = @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON; + ELSE + -- + -- This is not a valid json, we store it + -- + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, is_valid) + VALUES ( + NEW.objoid, + NEW.objsubid, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON + ) ON CONFLICT (objoid, objsubid) + DO UPDATE SET + is_valid = @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON; + END IF; RETURN NEW; END; -$$', schemaname, schemaname, schemaname, schemaname, schemaname, schemaname); + $fsub$; -- - -- Create two triggers, one for UPDATE and one for INSERT + -- Executed when a new column is created -- + CREATE OR REPLACE FUNCTION @extschema@.schedoc_column_trg() + RETURNS trigger LANGUAGE plpgsql AS $fsub$ + BEGIN + -- + -- + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, is_valid) + VALUES ( + NEW.attrelid, + NEW.attnum, + false + ) ON CONFLICT (objoid, objsubid) + DO UPDATE SET + is_valid = false; + + RETURN NEW; + END; + $fsub$; + + -- + -- Create triggers on INSERT + -- + CREATE TRIGGER schedoc_comment_trg + BEFORE INSERT ON @extschema@.ddl_history + FOR EACH ROW + WHEN (NEW.ddl_tag = 'COMMENT') + EXECUTE PROCEDURE @extschema@.schedoc_trg(); - 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); + CREATE TRIGGER schedoc_column_trg + BEFORE INSERT ON @extschema@.ddl_history_column + FOR EACH ROW + EXECUTE PROCEDURE @extschema@.schedoc_column_trg(); END; $EOF$; @@ -94,7 +159,7 @@ $EOF$; -- -- -- -CREATE OR REPLACE FUNCTION schedoc_get_column_description(bjoid oid, bjsubid oid) +CREATE OR REPLACE FUNCTION @extschema@.schedoc_get_column_description(bjoid oid, bjsubid oid) RETURNS text LANGUAGE plpgsql AS $EOF$ @@ -110,7 +175,7 @@ $EOF$; -- -- -- -CREATE OR REPLACE FUNCTION schedoc_get_column_status(bjoid oid, bjsubid oid) +CREATE OR REPLACE FUNCTION @extschema@.schedoc_get_column_status(bjoid oid, bjsubid oid) RETURNS text LANGUAGE plpgsql AS $EOF$ @@ -124,7 +189,43 @@ BEGIN END; $EOF$; -- +-- Remove the triggers and the functions to stop the process +-- +CREATE OR REPLACE FUNCTION @extschema@.schedoc_stop() +RETURNS void + LANGUAGE plpgsql AS +$EOF$ +BEGIN + -- + -- Remove all triggers + -- + DROP TRIGGER schedoc_comment_trg ON @extschema@.ddl_history; + DROP TRIGGER schedoc_column_trg ON @extschema@.ddl_history_column; + + -- + -- Remove all functions + -- + DROP FUNCTION @extschema@.schedoc_trg(); + DROP FUNCTION @extschema@.schedoc_column_trg(); + +END; +$EOF$; +-- +-- Check the schema of installation for schedoc -- -SELECT schedoc_start(); +DO +LANGUAGE plpgsql +$check_start$ +BEGIN + +IF NOT EXISTS (SELECT n.nspname FROM pg_extension e JOIN pg_namespace n ON n.oid=e.extnamespace + WHERE e.extname='ddl_historization' AND n.nspname='@extschema@') THEN + + RAISE EXCEPTION 'schedoc must be installed in the same schema as ddl_historization'; + +END IF; + +END; +$check_start$; $_pg_tle_$ ); diff --git a/dist/schedoc--0.0.2.sql b/dist/schedoc--0.0.2.sql index 8d999cc..0b369f3 100644 --- a/dist/schedoc--0.0.2.sql +++ b/dist/schedoc--0.0.2.sql @@ -8,9 +8,14 @@ CREATE TYPE schedoc_status AS ENUM ('public', 'private', 'legacy', 'wip'); -- as a foreign key target -- -- -CREATE TABLE schedoc_valid (status boolean NOT NULL PRIMARY KEY CHECK (status = true)); +CREATE TABLE @extschema@.schedoc_valid (status boolean NOT NULL PRIMARY KEY CHECK (status = true)); INSERT INTO schedoc_valid (status) VALUES (true); -- +-- +-- +CREATE TABLE @extschema@.schedoc_valid_status (status schedoc_status NOT NULL PRIMARY KEY); +INSERT INTO schedoc_valid_status VALUES ('public'), ('private'), ('legacy'), ('wip'); +-- -- 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. @@ -19,16 +24,30 @@ INSERT INTO schedoc_valid (status) VALUES (true); -- enforce that any new column creation must include in the same -- transaction a COMMENT statement. -- -CREATE TABLE schedoc_column_raw ( +CREATE TABLE @extschema@.schedoc_column_raw ( objoid oid, objsubid oid, comment jsonb, - is_valid boolean DEFAULT false REFERENCES schedoc_valid (status) DEFERRABLE INITIALLY DEFERRED, - status schedoc_status, + is_valid boolean DEFAULT false REFERENCES @extschema@.schedoc_valid (status) DEFERRABLE INITIALLY DEFERRED, + status schedoc_status REFERENCES @extschema@.schedoc_valid_status (status) DEFERRABLE INITIALLY DEFERRED, PRIMARY KEY (objoid, objsubid) ); -CREATE VIEW schedoc_column_comments AS +-- +-- +-- +CREATE TABLE @extschema@.schedoc_column_log ( + objoid oid, + objsubid oid, + comment text, + is_valid boolean DEFAULT false, + created_at timestamp with time zone DEFAULT current_timestamp +); +-- +-- +-- + +CREATE VIEW @extschema@.schedoc_column_comments AS SELECT current_database() as databasename, c.relname as tablename, a.attname as columnname, status FROM schedoc_column_raw ccr @@ -40,47 +59,93 @@ CREATE VIEW schedoc_column_comments AS -- -- -- -CREATE OR REPLACE FUNCTION schedoc_start() +CREATE OR REPLACE FUNCTION @extschema@.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 $$ + CREATE OR REPLACE FUNCTION @extschema@.schedoc_trg() + RETURNS trigger LANGUAGE plpgsql AS $fsub$ BEGIN - INSERT INTO %s.schedoc_column_raw (objoid, objsubid, comment, status) + + -- keep a log of all values + INSERT INTO @extschema@.schedoc_column_log (objoid, objsubid, comment, is_valid) + VALUES ( + NEW.objoid, + NEW.objsubid, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid), + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON + ); + + + -- if the json is valid + IF schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON THEN + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, comment, status, is_valid) 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 + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid)::jsonb, + @extschema@.schedoc_get_column_status(NEW.objoid, NEW.objsubid)::public.schedoc_status, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON ) 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; + comment = @extschema@.schedoc_get_column_description(EXCLUDED.objoid, EXCLUDED.objsubid)::jsonb, + status = @extschema@.schedoc_get_column_status(EXCLUDED.objoid, EXCLUDED.objsubid)::public.schedoc_status, + is_valid = @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON; + ELSE + -- + -- This is not a valid json, we store it + -- + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, is_valid) + VALUES ( + NEW.objoid, + NEW.objsubid, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON + ) ON CONFLICT (objoid, objsubid) + DO UPDATE SET + is_valid = @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON; + END IF; RETURN NEW; END; -$$', schemaname, schemaname, schemaname, schemaname, schemaname, schemaname); + $fsub$; -- - -- Create two triggers, one for UPDATE and one for INSERT + -- Executed when a new column is created -- + CREATE OR REPLACE FUNCTION @extschema@.schedoc_column_trg() + RETURNS trigger LANGUAGE plpgsql AS $fsub$ + BEGIN + -- + -- + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, is_valid) + VALUES ( + NEW.attrelid, + NEW.attnum, + false + ) ON CONFLICT (objoid, objsubid) + DO UPDATE SET + is_valid = false; + + RETURN NEW; + END; + $fsub$; + + -- + -- Create triggers on INSERT + -- + CREATE TRIGGER schedoc_comment_trg + BEFORE INSERT ON @extschema@.ddl_history + FOR EACH ROW + WHEN (NEW.ddl_tag = 'COMMENT') + EXECUTE PROCEDURE @extschema@.schedoc_trg(); - 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); + CREATE TRIGGER schedoc_column_trg + BEFORE INSERT ON @extschema@.ddl_history_column + FOR EACH ROW + EXECUTE PROCEDURE @extschema@.schedoc_column_trg(); END; $EOF$; @@ -88,7 +153,7 @@ $EOF$; -- -- -- -CREATE OR REPLACE FUNCTION schedoc_get_column_description(bjoid oid, bjsubid oid) +CREATE OR REPLACE FUNCTION @extschema@.schedoc_get_column_description(bjoid oid, bjsubid oid) RETURNS text LANGUAGE plpgsql AS $EOF$ @@ -104,7 +169,7 @@ $EOF$; -- -- -- -CREATE OR REPLACE FUNCTION schedoc_get_column_status(bjoid oid, bjsubid oid) +CREATE OR REPLACE FUNCTION @extschema@.schedoc_get_column_status(bjoid oid, bjsubid oid) RETURNS text LANGUAGE plpgsql AS $EOF$ @@ -118,5 +183,41 @@ BEGIN END; $EOF$; -- +-- Remove the triggers and the functions to stop the process +-- +CREATE OR REPLACE FUNCTION @extschema@.schedoc_stop() +RETURNS void + LANGUAGE plpgsql AS +$EOF$ +BEGIN + -- + -- Remove all triggers + -- + DROP TRIGGER schedoc_comment_trg ON @extschema@.ddl_history; + DROP TRIGGER schedoc_column_trg ON @extschema@.ddl_history_column; + + -- + -- Remove all functions + -- + DROP FUNCTION @extschema@.schedoc_trg(); + DROP FUNCTION @extschema@.schedoc_column_trg(); + +END; +$EOF$; +-- +-- Check the schema of installation for schedoc -- -SELECT schedoc_start(); +DO +LANGUAGE plpgsql +$check_start$ +BEGIN + +IF NOT EXISTS (SELECT n.nspname FROM pg_extension e JOIN pg_namespace n ON n.oid=e.extnamespace + WHERE e.extname='ddl_historization' AND n.nspname='@extschema@') THEN + + RAISE EXCEPTION 'schedoc must be installed in the same schema as ddl_historization'; + +END IF; + +END; +$check_start$; diff --git a/dist/schedoc.sql b/dist/schedoc.sql index 8d999cc..0b369f3 100644 --- a/dist/schedoc.sql +++ b/dist/schedoc.sql @@ -8,9 +8,14 @@ CREATE TYPE schedoc_status AS ENUM ('public', 'private', 'legacy', 'wip'); -- as a foreign key target -- -- -CREATE TABLE schedoc_valid (status boolean NOT NULL PRIMARY KEY CHECK (status = true)); +CREATE TABLE @extschema@.schedoc_valid (status boolean NOT NULL PRIMARY KEY CHECK (status = true)); INSERT INTO schedoc_valid (status) VALUES (true); -- +-- +-- +CREATE TABLE @extschema@.schedoc_valid_status (status schedoc_status NOT NULL PRIMARY KEY); +INSERT INTO schedoc_valid_status VALUES ('public'), ('private'), ('legacy'), ('wip'); +-- -- 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. @@ -19,16 +24,30 @@ INSERT INTO schedoc_valid (status) VALUES (true); -- enforce that any new column creation must include in the same -- transaction a COMMENT statement. -- -CREATE TABLE schedoc_column_raw ( +CREATE TABLE @extschema@.schedoc_column_raw ( objoid oid, objsubid oid, comment jsonb, - is_valid boolean DEFAULT false REFERENCES schedoc_valid (status) DEFERRABLE INITIALLY DEFERRED, - status schedoc_status, + is_valid boolean DEFAULT false REFERENCES @extschema@.schedoc_valid (status) DEFERRABLE INITIALLY DEFERRED, + status schedoc_status REFERENCES @extschema@.schedoc_valid_status (status) DEFERRABLE INITIALLY DEFERRED, PRIMARY KEY (objoid, objsubid) ); -CREATE VIEW schedoc_column_comments AS +-- +-- +-- +CREATE TABLE @extschema@.schedoc_column_log ( + objoid oid, + objsubid oid, + comment text, + is_valid boolean DEFAULT false, + created_at timestamp with time zone DEFAULT current_timestamp +); +-- +-- +-- + +CREATE VIEW @extschema@.schedoc_column_comments AS SELECT current_database() as databasename, c.relname as tablename, a.attname as columnname, status FROM schedoc_column_raw ccr @@ -40,47 +59,93 @@ CREATE VIEW schedoc_column_comments AS -- -- -- -CREATE OR REPLACE FUNCTION schedoc_start() +CREATE OR REPLACE FUNCTION @extschema@.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 $$ + CREATE OR REPLACE FUNCTION @extschema@.schedoc_trg() + RETURNS trigger LANGUAGE plpgsql AS $fsub$ BEGIN - INSERT INTO %s.schedoc_column_raw (objoid, objsubid, comment, status) + + -- keep a log of all values + INSERT INTO @extschema@.schedoc_column_log (objoid, objsubid, comment, is_valid) + VALUES ( + NEW.objoid, + NEW.objsubid, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid), + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON + ); + + + -- if the json is valid + IF schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON THEN + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, comment, status, is_valid) 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 + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid)::jsonb, + @extschema@.schedoc_get_column_status(NEW.objoid, NEW.objsubid)::public.schedoc_status, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON ) 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; + comment = @extschema@.schedoc_get_column_description(EXCLUDED.objoid, EXCLUDED.objsubid)::jsonb, + status = @extschema@.schedoc_get_column_status(EXCLUDED.objoid, EXCLUDED.objsubid)::public.schedoc_status, + is_valid = @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON; + ELSE + -- + -- This is not a valid json, we store it + -- + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, is_valid) + VALUES ( + NEW.objoid, + NEW.objsubid, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON + ) ON CONFLICT (objoid, objsubid) + DO UPDATE SET + is_valid = @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON; + END IF; RETURN NEW; END; -$$', schemaname, schemaname, schemaname, schemaname, schemaname, schemaname); + $fsub$; -- - -- Create two triggers, one for UPDATE and one for INSERT + -- Executed when a new column is created -- + CREATE OR REPLACE FUNCTION @extschema@.schedoc_column_trg() + RETURNS trigger LANGUAGE plpgsql AS $fsub$ + BEGIN + -- + -- + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, is_valid) + VALUES ( + NEW.attrelid, + NEW.attnum, + false + ) ON CONFLICT (objoid, objsubid) + DO UPDATE SET + is_valid = false; + + RETURN NEW; + END; + $fsub$; + + -- + -- Create triggers on INSERT + -- + CREATE TRIGGER schedoc_comment_trg + BEFORE INSERT ON @extschema@.ddl_history + FOR EACH ROW + WHEN (NEW.ddl_tag = 'COMMENT') + EXECUTE PROCEDURE @extschema@.schedoc_trg(); - 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); + CREATE TRIGGER schedoc_column_trg + BEFORE INSERT ON @extschema@.ddl_history_column + FOR EACH ROW + EXECUTE PROCEDURE @extschema@.schedoc_column_trg(); END; $EOF$; @@ -88,7 +153,7 @@ $EOF$; -- -- -- -CREATE OR REPLACE FUNCTION schedoc_get_column_description(bjoid oid, bjsubid oid) +CREATE OR REPLACE FUNCTION @extschema@.schedoc_get_column_description(bjoid oid, bjsubid oid) RETURNS text LANGUAGE plpgsql AS $EOF$ @@ -104,7 +169,7 @@ $EOF$; -- -- -- -CREATE OR REPLACE FUNCTION schedoc_get_column_status(bjoid oid, bjsubid oid) +CREATE OR REPLACE FUNCTION @extschema@.schedoc_get_column_status(bjoid oid, bjsubid oid) RETURNS text LANGUAGE plpgsql AS $EOF$ @@ -118,5 +183,41 @@ BEGIN END; $EOF$; -- +-- Remove the triggers and the functions to stop the process +-- +CREATE OR REPLACE FUNCTION @extschema@.schedoc_stop() +RETURNS void + LANGUAGE plpgsql AS +$EOF$ +BEGIN + -- + -- Remove all triggers + -- + DROP TRIGGER schedoc_comment_trg ON @extschema@.ddl_history; + DROP TRIGGER schedoc_column_trg ON @extschema@.ddl_history_column; + + -- + -- Remove all functions + -- + DROP FUNCTION @extschema@.schedoc_trg(); + DROP FUNCTION @extschema@.schedoc_column_trg(); + +END; +$EOF$; +-- +-- Check the schema of installation for schedoc -- -SELECT schedoc_start(); +DO +LANGUAGE plpgsql +$check_start$ +BEGIN + +IF NOT EXISTS (SELECT n.nspname FROM pg_extension e JOIN pg_namespace n ON n.oid=e.extnamespace + WHERE e.extname='ddl_historization' AND n.nspname='@extschema@') THEN + + RAISE EXCEPTION 'schedoc must be installed in the same schema as ddl_historization'; + +END IF; + +END; +$check_start$; diff --git a/sql/function-stop.sql b/sql/function-stop.sql new file mode 100644 index 0000000..6009ed7 --- /dev/null +++ b/sql/function-stop.sql @@ -0,0 +1,22 @@ +-- +-- Remove the triggers and the functions to stop the process +-- +CREATE OR REPLACE FUNCTION @extschema@.schedoc_stop() +RETURNS void + LANGUAGE plpgsql AS +$EOF$ +BEGIN + -- + -- Remove all triggers + -- + DROP TRIGGER schedoc_comment_trg ON @extschema@.ddl_history; + DROP TRIGGER schedoc_column_trg ON @extschema@.ddl_history_column; + + -- + -- Remove all functions + -- + DROP FUNCTION @extschema@.schedoc_trg(); + DROP FUNCTION @extschema@.schedoc_column_trg(); + +END; +$EOF$; diff --git a/sql/function.sql b/sql/function.sql index 2febaa6..fad97ef 100644 --- a/sql/function.sql +++ b/sql/function.sql @@ -1,47 +1,93 @@ -- -- -- -CREATE OR REPLACE FUNCTION schedoc_start() +CREATE OR REPLACE FUNCTION @extschema@.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 $$ + CREATE OR REPLACE FUNCTION @extschema@.schedoc_trg() + RETURNS trigger LANGUAGE plpgsql AS $fsub$ BEGIN - INSERT INTO %s.schedoc_column_raw (objoid, objsubid, comment, status) + + -- keep a log of all values + INSERT INTO @extschema@.schedoc_column_log (objoid, objsubid, comment, is_valid) + VALUES ( + NEW.objoid, + NEW.objsubid, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid), + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON + ); + + + -- if the json is valid + IF schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON THEN + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, comment, status, is_valid) + VALUES ( + NEW.objoid, + NEW.objsubid, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid)::jsonb, + @extschema@.schedoc_get_column_status(NEW.objoid, NEW.objsubid)::public.schedoc_status, + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON + ) ON CONFLICT (objoid, objsubid) + DO UPDATE SET + comment = @extschema@.schedoc_get_column_description(EXCLUDED.objoid, EXCLUDED.objsubid)::jsonb, + status = @extschema@.schedoc_get_column_status(EXCLUDED.objoid, EXCLUDED.objsubid)::public.schedoc_status, + is_valid = @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON; + ELSE + -- + -- This is not a valid json, we store it + -- + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, is_valid) 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 + @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON + ) ON CONFLICT (objoid, objsubid) + DO UPDATE SET + is_valid = @extschema@.schedoc_get_column_description(NEW.objoid, NEW.objsubid) IS JSON; + END IF; + RETURN NEW; + END; + $fsub$; + + -- + -- Executed when a new column is created + -- + CREATE OR REPLACE FUNCTION @extschema@.schedoc_column_trg() + RETURNS trigger LANGUAGE plpgsql AS $fsub$ + BEGIN + -- + -- + INSERT INTO @extschema@.schedoc_column_raw (objoid, objsubid, is_valid) + VALUES ( + NEW.attrelid, + NEW.attnum, + false ) 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; + is_valid = false; + RETURN NEW; END; -$$', schemaname, schemaname, schemaname, schemaname, schemaname, schemaname); + $fsub$; -- - -- Create two triggers, one for UPDATE and one for INSERT + -- Create triggers on INSERT -- + CREATE TRIGGER schedoc_comment_trg + BEFORE INSERT ON @extschema@.ddl_history + FOR EACH ROW + WHEN (NEW.ddl_tag = 'COMMENT') + EXECUTE PROCEDURE @extschema@.schedoc_trg(); - 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); + CREATE TRIGGER schedoc_column_trg + BEFORE INSERT ON @extschema@.ddl_history_column + FOR EACH ROW + EXECUTE PROCEDURE @extschema@.schedoc_column_trg(); END; $EOF$; @@ -49,7 +95,7 @@ $EOF$; -- -- -- -CREATE OR REPLACE FUNCTION schedoc_get_column_description(bjoid oid, bjsubid oid) +CREATE OR REPLACE FUNCTION @extschema@.schedoc_get_column_description(bjoid oid, bjsubid oid) RETURNS text LANGUAGE plpgsql AS $EOF$ @@ -65,7 +111,7 @@ $EOF$; -- -- -- -CREATE OR REPLACE FUNCTION schedoc_get_column_status(bjoid oid, bjsubid oid) +CREATE OR REPLACE FUNCTION @extschema@.schedoc_get_column_status(bjoid oid, bjsubid oid) RETURNS text LANGUAGE plpgsql AS $EOF$ diff --git a/sql/start.sql b/sql/start.sql index 217a45a..26fe3a1 100644 --- a/sql/start.sql +++ b/sql/start.sql @@ -1,3 +1,17 @@ -- +-- Check the schema of installation for schedoc -- -SELECT schedoc_start(); +DO +LANGUAGE plpgsql +$check_start$ +BEGIN + +IF NOT EXISTS (SELECT n.nspname FROM pg_extension e JOIN pg_namespace n ON n.oid=e.extnamespace + WHERE e.extname='ddl_historization' AND n.nspname='@extschema@') THEN + + RAISE EXCEPTION 'schedoc must be installed in the same schema as ddl_historization'; + +END IF; + +END; +$check_start$; diff --git a/sql/table.sql b/sql/table.sql index 033c2fa..842eaa5 100644 --- a/sql/table.sql +++ b/sql/table.sql @@ -8,9 +8,14 @@ CREATE TYPE schedoc_status AS ENUM ('public', 'private', 'legacy', 'wip'); -- as a foreign key target -- -- -CREATE TABLE schedoc_valid (status boolean NOT NULL PRIMARY KEY CHECK (status = true)); +CREATE TABLE @extschema@.schedoc_valid (status boolean NOT NULL PRIMARY KEY CHECK (status = true)); INSERT INTO schedoc_valid (status) VALUES (true); -- +-- +-- +CREATE TABLE @extschema@.schedoc_valid_status (status schedoc_status NOT NULL PRIMARY KEY); +INSERT INTO schedoc_valid_status VALUES ('public'), ('private'), ('legacy'), ('wip'); +-- -- 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. @@ -19,16 +24,30 @@ INSERT INTO schedoc_valid (status) VALUES (true); -- enforce that any new column creation must include in the same -- transaction a COMMENT statement. -- -CREATE TABLE schedoc_column_raw ( +CREATE TABLE @extschema@.schedoc_column_raw ( objoid oid, objsubid oid, comment jsonb, - is_valid boolean DEFAULT false REFERENCES schedoc_valid (status) DEFERRABLE INITIALLY DEFERRED, - status schedoc_status, + is_valid boolean DEFAULT false REFERENCES @extschema@.schedoc_valid (status) DEFERRABLE INITIALLY DEFERRED, + status schedoc_status REFERENCES @extschema@.schedoc_valid_status (status) DEFERRABLE INITIALLY DEFERRED, PRIMARY KEY (objoid, objsubid) ); -CREATE VIEW schedoc_column_comments AS +-- +-- +-- +CREATE TABLE @extschema@.schedoc_column_log ( + objoid oid, + objsubid oid, + comment text, + is_valid boolean DEFAULT false, + created_at timestamp with time zone DEFAULT current_timestamp +); +-- +-- +-- + +CREATE VIEW @extschema@.schedoc_column_comments AS SELECT current_database() as databasename, c.relname as tablename, a.attname as columnname, status FROM schedoc_column_raw ccr diff --git a/test/create_column.sql b/test/create_column.sql index 1b278da..d18b3dc 100644 --- a/test/create_column.sql +++ b/test/create_column.sql @@ -5,6 +5,10 @@ SET search_path=public,pgtap; BEGIN; +DROP EXTENSION IF EXISTS schedoc CASCADE; +CREATE EXTENSION schedoc CASCADE; +SELECT schedoc_start(); + SELECT plan(4); TRUNCATE ddl_history; diff --git a/test/create_table.sql b/test/create_table.sql index f8d9271..6b34193 100644 --- a/test/create_table.sql +++ b/test/create_table.sql @@ -6,6 +6,10 @@ SET search_path=public,pgtap; BEGIN; +DROP EXTENSION IF EXISTS schedoc CASCADE; +CREATE EXTENSION schedoc CASCADE; +SELECT schedoc_start(); + SELECT plan(2); TRUNCATE ddl_history; diff --git a/test/integration_tests.sql b/test/integration_tests.sql index 3a757aa..bc39c03 100644 --- a/test/integration_tests.sql +++ b/test/integration_tests.sql @@ -6,15 +6,15 @@ SET search_path=public,pgtap; BEGIN; -SELECT plan(9); +SELECT plan(11); TRUNCATE ddl_history; --- 2 -CREATE TABLE foobar_schedoc (id int); - DROP EXTENSION IF EXISTS schedoc CASCADE; CREATE EXTENSION schedoc CASCADE; +SELECT schedoc_start(); +-- 2 +CREATE TABLE foobar_schedoc (id int); -- add test on schema to fail fast SELECT has_extension('schedoc'); @@ -26,14 +26,14 @@ ALTER TABLE foobar_schedoc ADD COLUMN toto int; CREATE INDEX ON foobar_schedoc (toto); -- -TRUNCATE ddl_history; +TRUNCATE schedoc_column_raw; COMMENT ON COLUMN foobar_schedoc.id IS '{"status": "private"}'; -- SELECT results_eq( 'SELECT count(*) FROM ddl_history', 'SELECT CAST(1 as bigint)', - 'We have 1 row in ddl_history'); + 'We have 1 rows in ddl_history'); SELECT results_eq( 'SELECT count(*) FROM schedoc_column_raw', @@ -90,7 +90,44 @@ SELECT throws_ok( 'We should get an input syntax error' ); +-- +-- The comment is not in JSONB format +-- +CREATE OR REPLACE FUNCTION setcomm_wrong_format_b() +RETURNS void + LANGUAGE plpgsql AS +$EOF$ +BEGIN + COMMENT ON COLUMN foobar_schedoc.id IS '{"this":"is json"}'; +END; +$EOF$; + +PREPARE wrong_format_b AS SELECT * FROM setcomm_wrong_format_b(); +SELECT throws_ok( + 'wrong_format_b', + '22P02', + 'invalid input syntax for type json', + 'We should get an input syntax error' +); +-- +-- +-- + + +COMMENT ON COLUMN foobar_schedoc.id IS 'bad comment'; +COMMENT ON COLUMN foobar_schedoc.id IS '{"status": "private", "kt": "0/F8517A10"}'; + + + +SELECT results_eq( + 'SELECT count(*) FROM schedoc_column_raw WHERE comment->>''kt'' = ''0/F8517A10'' ', + 'SELECT CAST(1 as bigint)', + 'Bad comment are allowed if fixed later in the transaction'); + +-- +-- Null comment are allowed +-- COMMENT ON COLUMN foobar_schedoc.id IS NULL; ROLLBACK; diff --git a/test/sql/function-stop_test.sql b/test/sql/function-stop_test.sql new file mode 100644 index 0000000..5d2a14c --- /dev/null +++ b/test/sql/function-stop_test.sql @@ -0,0 +1,16 @@ +-- +-- We assume that ddl_historization is installed in public schema +-- + +SET search_path=public,pgtap; + +BEGIN; + +SELECT plan(2); + +SELECT has_extension('schedoc'); + +SELECT has_function('schedoc_stop'); + + +ROLLBACK; diff --git a/test/start_stop_tests.sql b/test/start_stop_tests.sql new file mode 100644 index 0000000..0efc9b7 --- /dev/null +++ b/test/start_stop_tests.sql @@ -0,0 +1,35 @@ +-- +-- We assume that ddl_historization is installed in public schema +-- + +SET search_path=public,pgtap; + +BEGIN; + +SELECT plan(13); + +-- fail fast if the extension is not installed +SELECT has_extension('schedoc'); + +SELECT schedoc_start(); + +SELECT has_function('schedoc_trg'); +SELECT has_function('schedoc_column_trg'); +SELECT has_trigger('ddl_history'::name, 'schedoc_comment_trg'::name); +SELECT has_trigger('ddl_history_column'::name, 'schedoc_column_trg'::name); + +SELECT schedoc_stop(); + +SELECT hasnt_function('schedoc_trg'); +SELECT hasnt_function('schedoc_column_trg'); +SELECT hasnt_trigger('ddl_history'::name, 'schedoc_comment_trg'::name); +SELECT hasnt_trigger('ddl_history_column'::name, 'schedoc_column_trg'::name); + +SELECT schedoc_start(); + +SELECT has_function('schedoc_trg'); +SELECT has_function('schedoc_column_trg'); +SELECT has_trigger('ddl_history'::name, 'schedoc_comment_trg'::name); +SELECT has_trigger('ddl_history_column'::name, 'schedoc_column_trg'::name); + +ROLLBACK;