Mercurial > libervia-pubsub
view db/pubsub.sql @ 478:b544109ab4c4
Privileged Entity update + Pubsub Account Management partial implementation + Public Pubsub Subscription
/!\ pgsql schema needs to be updated /!\
/!\ server conf needs to be updated for privileged entity: only the new
`urn:xmpp:privilege:2` namespace is handled now /!\
Privileged entity has been updated to hanlde the new namespace and IQ permission. Roster
pushes are not managed yet.
XEP-0376 (Pubsub Account Management) is partially implemented. The XEP is not fully
specified at the moment, and my messages on standard@ haven't seen any reply. Thus for now
only "Subscribing", "Unsubscribing" and "Listing Subscriptions" is implemented, "Auto
Subscriptions" and "Filtering" is not.
Public Pubsub Subscription
(https://xmpp.org/extensions/inbox/pubsub-public-subscriptions.html) is implemented;
the XEP has been accepted by council but is not yet published. It will be updated to use
subscription options instead of the <public> element actually specified, I'm waiting
for publication to update the XEP.
unsubscribe has been updated to return the `<subscription>` element as expected by
XEP-0060 (sat_tmp needs to be updated).
database schema has been updated to add columns necessary to keep track of subscriptions
to external nodes and to mark subscriptions as public.
author | Goffi <goffi@goffi.org> |
---|---|
date | Wed, 11 May 2022 13:39:08 +0200 |
parents | 0d38c3529972 |
children | cfa40fa108a4 |
line wrap: on
line source
CREATE TABLE entities ( entity_id serial PRIMARY KEY, jid text NOT NULL UNIQUE ); CREATE TABLE nodes ( node_id serial PRIMARY KEY, node text NOT NULL, pep text, node_type text NOT NULL DEFAULT 'leaf' CHECK (node_type IN ('leaf', 'collection')), access_model text NOT NULL DEFAULT 'open' CHECK (access_model IN ('open', 'presence', 'publisher-roster', 'whitelist', 'publish-only', 'self-publisher')), persist_items boolean, deliver_payloads boolean NOT NULL DEFAULT TRUE, max_items integer NOT NULL DEFAULT 0 CHECK (max_items >= 0), overwrite_policy text NOT NULL DEFAULT 'original_publisher' CHECK (overwrite_policy IN ('original_publisher', 'any_publisher')), serial_ids boolean NOT NULL DEFAULT FALSE, consistent_publisher boolean NOT NULL DEFAULT FALSE, fts_language text NOT NULL DEFAULT 'generic', send_last_published_item text NOT NULL DEFAULT 'on_sub' CHECK (send_last_published_item IN ('never', 'on_sub')), publish_model text NOT NULL DEFAULT 'publishers' CHECK (publish_model IN ('publishers', 'subscribers', 'open')), schema xml ); /* we need 2 partial indexes to manage NULL value for PEP */ CREATE UNIQUE INDEX nodes_node_pep_key_not_null ON nodes(node, pep) WHERE pep IS NOT NULL; CREATE UNIQUE INDEX nodes_node_pep_key_null ON nodes(node) WHERE pep IS NULL; INSERT INTO nodes (node, node_type) values ('', 'collection'); CREATE TABLE affiliations ( affiliation_id serial PRIMARY KEY, entity_id integer NOT NULL REFERENCES entities ON DELETE CASCADE, node_id integer NOT NULL references nodes ON DELETE CASCADE, affiliation text NOT NULL CHECK (affiliation IN ('outcast', 'member', 'publisher', 'owner')), UNIQUE (entity_id, node_id) ); CREATE TABLE node_groups_authorized ( node_groups_authorized_id serial PRIMARY KEY, node_id integer NOT NULL references nodes ON DELETE CASCADE, groupname text NOT NULL, UNIQUE (node_id,groupname) ); CREATE TABLE subscriptions ( subscription_id serial PRIMARY KEY, entity_id integer NOT NULL REFERENCES entities ON DELETE CASCADE, resource text, node_id integer REFERENCES nodes ON DELETE CASCADE, /* when we reference an external node (with PAM), node_id is NULL and service and node * are set */ ext_service text, ext_node text, state text NOT NULL DEFAULT 'subscribed' CHECK (state IN ('subscribed', 'pending', 'unconfigured')), subscription_type text CHECK (subscription_type IN (NULL, 'items', 'nodes')), subscription_depth text CHECK (subscription_depth IN (NULL, '1', 'all')), public boolean NOT NULL DEFAULT FALSE, UNIQUE (entity_id, resource, node_id)), UNIQUE (entity_id, ext_service, ext_node)), ; CREATE TABLE items ( item_id serial PRIMARY KEY, node_id integer NOT NULL REFERENCES nodes ON DELETE CASCADE, item text NOT NULL, publisher text NOT NULL, data xml NOT NULL, data_fts tsvector, data_fts_cfg text NOT NULL DEFAULT 'simple', access_model text NOT NULL DEFAULT 'open' CHECK (access_model IN ('open', 'publisher-roster', 'whitelist')), created timestamp with time zone NOT NULL DEFAULT now(), updated timestamp with time zone NOT NULL DEFAULT now(), UNIQUE (node_id, item) ); CREATE TABLE item_groups_authorized ( item_groups_authorized_id serial PRIMARY KEY, item_id integer NOT NULL references items ON DELETE CASCADE, groupname text NOT NULL, UNIQUE (item_id,groupname) ); 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) ); CREATE TABLE item_categories ( item_categories_id serial PRIMARY KEY, item_id integer NOT NULL references items ON DELETE CASCADE, category text NOT NULL, UNIQUE (item_id,category) ); /* Full Text Search */ CREATE INDEX items_data_fts ON items USING GIN (data_fts); CREATE OR REPLACE FUNCTION update_data_fts_cfg() RETURNS TRIGGER AS $$ BEGIN UPDATE items SET data_fts_cfg=replace(new.fts_language, 'generic', 'simple') WHERE items.node_id=new.node_id AND NOT EXISTS(SELECT FROM item_languages AS lang WHERE lang.item_id=items.item_id); RETURN new; END; $$ language plpgsql; CREATE TRIGGER nodes_fts_language_update AFTER UPDATE OF fts_language ON nodes FOR EACH ROW EXECUTE PROCEDURE update_data_fts_cfg(); CREATE FUNCTION update_data_fts() RETURNS TRIGGER AS $$ BEGIN new.data_fts=to_tsvector(new.data_fts_cfg::regconfig, new.data::text); RETURN new; END $$ language plpgsql; CREATE TRIGGER items_fts_tsvector_update BEFORE INSERT OR UPDATE OF data_fts_cfg,data ON items FOR EACH ROW EXECUTE PROCEDURE update_data_fts(); /* Roster */ CREATE TABLE roster ( roster_id serial PRIMARY KEY, jid text NOT NULL UNIQUE, version text, updated timestamp with time zone NOT NULL, roster xml NOT NULL ); CREATE TABLE metadata ( key text PRIMARY KEY, value text ); INSERT INTO metadata VALUES ('version', '10');