diff --git a/rest-api/db/migrations/20240719071602_main_tables.sql b/rest-api/db/migrations/20240719071602_main_tables.sql index 3dc9e69..e1fce1a 100644 --- a/rest-api/db/migrations/20240719071602_main_tables.sql +++ b/rest-api/db/migrations/20240719071602_main_tables.sql @@ -82,6 +82,8 @@ CREATE TABLE internal.docs_category ( user_id UUID REFERENCES internal.user (id) ON DELETE SET NULL DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID, category_name VARCHAR(50) NOT NULL CHECK (TRIM(category_name) != ''), category_weight INTEGER CHECK (category_weight >= 0) NOT NULL, + last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(), + last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL, UNIQUE (website_id, category_name), UNIQUE (website_id, category_weight) ); @@ -94,14 +96,15 @@ CREATE TABLE internal.article ( meta_description VARCHAR(250) CHECK (TRIM(meta_description) != ''), meta_author VARCHAR(100) CHECK (TRIM(meta_author) != ''), cover_image UUID REFERENCES internal.media (id) ON DELETE SET NULL, - publication_date DATE DEFAULT CURRENT_DATE, + publication_date DATE, main_content TEXT CHECK (TRIM(main_content) != ''), category UUID REFERENCES internal.docs_category (id) ON DELETE SET NULL, article_weight INTEGER CHECK (article_weight IS NULL OR article_weight >= 0), created_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(), last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(), last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL, - title_description_search TSVECTOR GENERATED ALWAYS AS (TO_TSVECTOR('english', COALESCE(title, '') || ' ' || COALESCE(meta_description, ''))) STORED + title_description_search TSVECTOR GENERATED ALWAYS AS (TO_TSVECTOR('english', COALESCE(title, '') || ' ' || COALESCE(meta_description, ''))) STORED, + UNIQUE (website_id, category, article_weight) ); CREATE TABLE internal.footer ( @@ -128,19 +131,7 @@ CREATE TABLE internal.collab ( PRIMARY KEY (website_id, user_id) ); -CREATE TABLE internal.change_log ( - website_id UUID REFERENCES internal.website (id) ON DELETE CASCADE, - user_id UUID REFERENCES internal.user (id) ON DELETE CASCADE DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID, - change_summary VARCHAR(255) NOT NULL, - previous_value JSONB, - new_value JSONB, - timestamp TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(), - PRIMARY KEY (website_id, user_id, TIMESTAMP) -); - -- migrate:down -DROP TABLE internal.change_log; - DROP TABLE internal.collab; DROP TABLE internal.legal_information; diff --git a/rest-api/db/migrations/20240720132802_exposed_views_functions.sql b/rest-api/db/migrations/20240720132802_exposed_views_functions.sql index 48aeffb..1611e91 100644 --- a/rest-api/db/migrations/20240720132802_exposed_views_functions.sql +++ b/rest-api/db/migrations/20240720132802_exposed_views_functions.sql @@ -82,13 +82,6 @@ SELECT FROM internal.collab; -CREATE VIEW api.change_log WITH ( security_invoker = ON -) AS -SELECT - * -FROM - internal.change_log; - CREATE FUNCTION api.create_website (content_type VARCHAR(10), title VARCHAR(50), OUT website_id UUID) AS $$ DECLARE @@ -170,15 +163,9 @@ GRANT SELECT, INSERT, UPDATE, DELETE ON internal.collab TO authenticated_user; GRANT SELECT, INSERT, UPDATE, DELETE ON api.collab TO authenticated_user; -GRANT SELECT ON internal.change_log TO authenticated_user; - -GRANT SELECT ON api.change_log TO authenticated_user; - -- migrate:down DROP FUNCTION api.create_website (VARCHAR(10), VARCHAR(50)); -DROP VIEW api.change_log; - DROP VIEW api.collab; DROP VIEW api.legal_information; diff --git a/rest-api/db/migrations/20240805132306_last_modified_triggers.sql b/rest-api/db/migrations/20240805132306_last_modified_triggers.sql index 9a9a07b..a33c109 100644 --- a/rest-api/db/migrations/20240805132306_last_modified_triggers.sql +++ b/rest-api/db/migrations/20240805132306_last_modified_triggers.sql @@ -44,6 +44,11 @@ CREATE TRIGGER update_article_last_modified FOR EACH ROW EXECUTE FUNCTION internal.update_last_modified (); +CREATE TRIGGER update_docs_category_modified + BEFORE INSERT OR UPDATE OR DELETE ON internal.docs_category + FOR EACH ROW + EXECUTE FUNCTION internal.update_last_modified (); + CREATE TRIGGER update_footer_last_modified BEFORE UPDATE ON internal.footer FOR EACH ROW @@ -70,6 +75,8 @@ DROP TRIGGER update_home_last_modified ON internal.home; DROP TRIGGER update_article_last_modified ON internal.article; +DROP TRIGGER update_docs_category_modified ON internal.docs_category; + DROP TRIGGER update_footer_last_modified ON internal.footer; DROP TRIGGER update_legal_information_last_modified ON internal.legal_information; diff --git a/rest-api/db/migrations/20240911070907_change_log.sql b/rest-api/db/migrations/20240911070907_change_log.sql new file mode 100644 index 0000000..d07a581 --- /dev/null +++ b/rest-api/db/migrations/20240911070907_change_log.sql @@ -0,0 +1,126 @@ +-- migrate:up +CREATE EXTENSION hstore; + +CREATE TABLE internal.change_log ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid (), + website_id UUID REFERENCES internal.website (id) ON DELETE CASCADE, + user_id UUID REFERENCES internal.user (id) ON DELETE CASCADE DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID, + tstamp TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(), + table_name TEXT NOT NULL, + operation TEXT NOT NULL, + old_value HSTORE, + new_value HSTORE +); + +CREATE FUNCTION internal.track_changes () + RETURNS TRIGGER + AS $$ +DECLARE + _website_id UUID; +BEGIN + IF TG_TABLE_NAME = 'website' THEN + _website_id := NEW.id; + ELSE + _website_id := NEW.website_id; + END IF; + IF TG_OP = 'INSERT' THEN + INSERT INTO internal.change_log (website_id, table_name, operation, new_value) + VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (NEW)); + RETURN NEW; + ELSIF TG_OP = 'UPDATE' THEN + INSERT INTO internal.change_log (website_id, table_name, operation, old_value, new_value) + VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (OLD) - HSTORE (NEW), HSTORE (NEW) - HSTORE (OLD)); + RETURN NEW; + ELSIF TG_OP = 'DELETE' THEN + INSERT INTO internal.change_log (website_id, table_name, operation, old_value) + VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (OLD)); + RETURN NEW; + END IF; +END; +$$ +LANGUAGE plpgsql +SECURITY DEFINER; + +CREATE TRIGGER website_track_changes + AFTER INSERT OR UPDATE OR DELETE ON internal.website + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER settings_track_changes + AFTER UPDATE ON internal.settings + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER header_track_changes + AFTER UPDATE ON internal.header + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER home_track_changes + AFTER UPDATE ON internal.home + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER article_track_changes + AFTER INSERT OR UPDATE OR DELETE ON internal.article + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER docs_category_track_changes + AFTER INSERT OR UPDATE OR DELETE ON internal.docs_category + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER footer_track_changes + AFTER UPDATE ON internal.footer + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER legal_information_track_changes + AFTER UPDATE ON internal.legal_information + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER collab_track_changes + AFTER INSERT OR UPDATE OR DELETE ON internal.collab + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE VIEW api.change_log WITH ( security_invoker = ON +) AS +SELECT + * +FROM + internal.change_log; + +GRANT SELECT ON internal.change_log TO authenticated_user; + +GRANT SELECT ON api.change_log TO authenticated_user; + +-- migrate:down +DROP TRIGGER website_track_changes ON internal.website; + +DROP TRIGGER settings_track_changes ON internal.settings; + +DROP TRIGGER header_track_changes ON internal.header; + +DROP TRIGGER home_track_changes ON internal.home; + +DROP TRIGGER article_track_changes ON internal.article; + +DROP TRIGGER docs_category_track_changes ON internal.docs_category; + +DROP TRIGGER footer_track_changes ON internal.footer; + +DROP TRIGGER legal_information_track_changes ON internal.legal_information; + +DROP TRIGGER collab_track_changes ON internal.collab; + +DROP FUNCTION internal.track_changes (); + +DROP VIEW api.change_log; + +DROP TABLE internal.change_log; + +DROP EXTENSION hstore; + diff --git a/web-app/src/lib/components/DateTime.svelte b/web-app/src/lib/components/DateTime.svelte index 4bc6bae..b2ba649 100644 --- a/web-app/src/lib/components/DateTime.svelte +++ b/web-app/src/lib/components/DateTime.svelte @@ -11,6 +11,6 @@ }; -