diff db/sat_pubsub_update_1_2.sql @ 350:4d4575911060

sql (PostgreSQL): schema update: - added version check on top of update files, SQL will not be applied if the version is not the one expected - new db schema version (3) - added "presence" access_model in nodes - added "schema" column in nodes - converted items data to xml, this will allow the use of all XML functions PostgreSQL now needs to have been compiled with --with-libxml .
author Goffi <goffi@goffi.org>
date Fri, 08 Sep 2017 08:02:04 +0200
parents db/sat_pubsub_update_0_2.sql@98409ef42c94
children 1dc606612405
line wrap: on
line diff
--- /dev/null	Thu Jan 01 00:00:00 1970 +0000
+++ b/db/sat_pubsub_update_1_2.sql	Fri Sep 08 08:02:04 2017 +0200
@@ -0,0 +1,42 @@
+-- we check version of the database before doing anything
+-- and stop execution if not good
+\set ON_ERROR_STOP
+DO $$
+DECLARE ver smallint;
+BEGIN
+    SELECT value INTO ver FROM metadata WHERE key='version';
+    IF NOT FOUND OR ver!='1' THEN
+        RAISE EXCEPTION 'This update file need to be applied on database schema version 1, you use version %',ver;
+    END IF;
+END$$;
+\unset ON_ERROR_STOP
+-- end of version check
+
+/* roster access model was badly used, we rename it to publisher-roster */
+
+ALTER TABLE nodes DROP CONSTRAINT nodes_access_model_check;
+UPDATE nodes SET access_model = 'publisher-roster' WHERE access_model = 'roster';
+ALTER TABLE nodes ADD CHECK (access_model IN ('open', 'publisher-roster', 'whitelist', 'publish-only', 'self-publisher'));
+
+ALTER TABLE items DROP CONSTRAINT items_access_model_check;
+UPDATE items SET access_model = 'publisher-roster' WHERE access_model = 'roster';
+ALTER TABLE items ADD CHECK (access_model IN ('open', 'publisher-roster', 'whitelist'));
+
+ALTER TABLE affiliations DROP CONSTRAINT affiliations_affiliation_check;
+ALTER TABLE affiliations ADD CHECK (affiliation IN ('outcast', 'member', 'publisher', 'owner'));
+
+CREATE TABLE item_jids_authorized (
+    item_jids_authorized_id serial PRIMARY KEY,
+    item_id integer NOT NULL references items ON DELETE CASCADE,
+    jid text NOT NULL,
+    UNIQUE (item_id,jid)
+);
+
+CREATE TABLE item_languages (
+    item_languages_id serial PRIMARY KEY,
+    item_id integer NOT NULL references items ON DELETE CASCADE,
+    language text NOT NULL,
+    UNIQUE (item_id,language)
+);
+
+UPDATE metadata SET value='2' WHERE key='version';